Partition-wise join for join between (declaratively) partitioned tables
Amit Langote is working on supporting declarative partitioning in
PostgreSQL [1]. /messages/by-id/55D3093C.5010800@lab.ntt.co.jp. I have started working on supporting partition-wise join.
This mail describes very high level design and some insight into the
performance improvements.
An equi-join between two partitioned tables can be broken down into
pair-wise join between their partitions. This technique is called
partition-wise join. Partition-wise joins between similarly partitioned
tables with equi-join condition can be efficient because [2]. https://users.cs.duke.edu/~shivnath/papers/sigmod295-herodotou.pdf
1. Each provably non-empty partition-wise join smaller. All such joins
collectively might be more efficient than the join between their parent.
2. Such joins are able to exploit properties of partitions like indexes,
their storage etc.
3. An N-way partition-wise join may have different efficient join orders
compared to the efficient join order between the parent tables.
A partition-wise join is processed in following stages [2]. https://users.cs.duke.edu/~shivnath/papers/sigmod295-herodotou.pdf, [3]. https://users.cs.duke.edu/~shivnath/tmp/paqo_draft.pdf.
1. Applicability testing: This phase checks if the join conditions match
the partitioning scheme. A partition-wise join is efficient if there is an
equi-join on the partition keys. E.g. join between tables R and S
partitioned by columns a and b resp. can be broken down into partition-wise
joins if there exists a join condition is R.a = S.b. Or in other words the
number of provably non-empty partition-wise joins is O(N) where N is the
number of partitions.
2. Matching: This phase determines which joins between the partitions of R
and S can potentially produce tuples in the join and prunes empty joins
between partitions.
3. Clustering: This phase aims at reducing the number of partition-wise
joins by clubbing together partitions from joining relations. E.g. clubbing
multiple partitions from either of the partitioned relations which can join
to a single partition from the other partitioned relation.
4. Path/plan creation: This phase creates multiple paths for each
partition-wise join. It also creates Append path/s representing the union
of partition-wise joins.
The work here focuses on a subset of use-cases discussed in [2]. https://users.cs.duke.edu/~shivnath/papers/sigmod295-herodotou.pdf. It only
considers partition-wise join for join between similarly partitioned tables
with same number of partitions with same properties, thus producing at most
as many partition-wise joins as there are partitions. It should be possible
to apply partition-wise join technique (with some special handling for
OUTER joins) if both relations have some extra partitions with
non-overlapping partition conditions, apart from the matching partitions.
But I am not planning to implement this optimization in the first cut.
The attached patch is a POC implementation of partition-wise join. It is is
based on the set of patches posted on 23rd May 2016 by Amit Langote for
declarative partitioning. The patch gives an idea about the approach used.
It has several TODOs, which I am working on.
Attached is a script with output which measures potential performance
improvement because of partition-wise join. The script uses a GUC
enable_partition_wise_join to disable/enable this feature for performance
measurement. The scripts measures performance improvement of a join between
two tables partitioned by range on integer column. Each table contains 50K
rows. Each table has an integer and a varchar column. It shows around
10-15% reduction in execution time when partition-wise join is used.
Accompanied with parallel query and FDWs, it opens up avenues for further
improvements for joins between partitioned tables.
[1]: . /messages/by-id/55D3093C.5010800@lab.ntt.co.jp
[2]: . https://users.cs.duke.edu/~shivnath/papers/sigmod295-herodotou.pdf
[3]: . https://users.cs.duke.edu/~shivnath/tmp/paqo_draft.pdf
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_POC.patchtext/x-diff; charset=US-ASCII; name=pg_dp_join_POC.patchDownload
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 873a764..e8c7c76 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -987,21 +987,59 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
if (rel->has_eclass_joins || has_useful_pathkeys(root, rel))
add_child_rel_equivalences(root, appinfo, rel, childrel);
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
* Note: we could compute appropriate attr_needed data for the child's
* variables, by transforming the parent's attr_needed through the
* translated_vars mapping. However, currently there's no need
* because attr_needed is only examined for base relations not
* otherrels. So we just leave the child's attr_needed empty.
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for buiding pair-wise
+ * join relations. Partition tables should have same layout as the
+ * parent table and hence should not need any translation. But rest of
+ * the code still uses inheritance mechanism. So do we here.
+ * TODO: do we need to translate the relids as well?
*/
+ if (rel->part_desc && rel->part_desc->nparts > 0)
+ {
+ AttrNumber attno;
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /* Parent Var translates to child Var. */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
+ }
/*
* Compute the child's size.
*/
set_rel_size(root, childrel, childRTindex, childRTE);
/*
* It is possible that constraint exclusion detected a contradiction
* within a child subquery, even though we didn't prove one above. If
* so, we can skip this child.
@@ -1097,34 +1135,38 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
{
int parentRTindex = rti;
List *live_childrels = NIL;
List *subpaths = NIL;
bool subpaths_valid = true;
List *partial_subpaths = NIL;
bool partial_subpaths_valid = true;
List *all_child_pathkeys = NIL;
List *all_child_outers = NIL;
ListCell *l;
+ PartitionDesc part_desc = rel->part_desc;
+ int num_parts = part_desc ? part_desc->nparts : 0;
+ Oid *part_oids = part_desc ? part_desc->oids : NULL;
/*
* Generate access paths for each member relation, and remember the
* cheapest path for each one. Also, identify all pathkeys (orderings)
* and parameterizations (required_outer sets) available for the member
* relations.
*/
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
ListCell *lcp;
+ int cnt_parts;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
/* Re-locate the child RTE and RelOptInfo */
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
childrel = root->simple_rel_array[childRTindex];
@@ -1132,20 +1174,37 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* Compute the child's access paths.
*/
set_rel_pathlist(root, childrel, childRTindex, childRTE);
/*
* If child is dummy, ignore it.
*/
if (IS_DUMMY_REL(childrel))
continue;
+ /*
+ * Match the children to the partition to fill the partition scheme by
+ * matching OID of the children in part_desc and RTE.
+ * TODO: we are doing this here since we get hold of the partition
+ * RelOptInfo here. But we should assess whether this is the right
+ * place.
+ */
+ for (cnt_parts = 0; cnt_parts < num_parts; cnt_parts++)
+ {
+ if (part_oids[cnt_parts] == childRTE->relid)
+ {
+ /* Every partition can be seen only once. */
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+
/*
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
/*
* If child has an unparameterized cheapest-total path, add that to
* the unparameterized Append path we are constructing for the parent.
* If not, there's no workable unparameterized path.
*/
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 4c9d8d9..9cd0361 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -120,20 +120,21 @@ bool enable_indexscan = true;
bool enable_indexonlyscan = true;
bool enable_bitmapscan = true;
bool enable_tidscan = true;
bool enable_sort = true;
bool enable_hashagg = true;
bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
bool enable_fkey_estimates = true;
+bool enable_partition_wise_join = true;
typedef struct
{
PlannerInfo *root;
QualCost total;
} cost_qual_eval_context;
static List *extract_nonindex_conditions(List *qual_clauses, List *indexquals);
static MergeScanSelCache *cached_scansel(PlannerInfo *root,
RestrictInfo *rinfo,
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..b0cbc1b 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -10,35 +10,42 @@
* IDENTIFICATION
* src/backend/optimizer/path/joinrels.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
static void make_rels_by_clause_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static void make_rels_by_clauseless_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static bool are_partitions_joinable(RelOptInfo *rel1, RelOptInfo *rel2,
+ SpecialJoinInfo *sjinfo);
+static PartitionDesc build_joinrel_partition_desc(RelOptInfo *rel1,
+ RelOptInfo *rel2,
+ SpecialJoinInfo *sjinfo);
+static void add_append_paths_to_joinrel(RelOptInfo *joinrel);
/*
* join_search_one_level
* Consider ways to produce join relations containing exactly 'level'
* jointree items. (This is one step of the dynamic-programming method
* embodied in standard_join_search.) Join rel nodes for each feasible
* combination of lower-level rels are created and returned in a list.
* Implementation paths are created for each such joinrel, too.
*
@@ -862,25 +869,182 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
break;
default:
/* other values not expected here */
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
+ /*
+ * If both the relations are partitioned in the same way, and there is an
+ * equi-join clause on partition key, try joining the partitions. Store the
+ * partitioning scheme in joinrel for further joins.
+ */
+
+ joinrel->part_desc = build_joinrel_partition_desc(rel1, rel2, sjinfo);
+
+ if (joinrel->part_desc && joinrel->part_desc->nparts > 0)
+ {
+ int nparts = joinrel->part_desc->nparts;
+ int cnt_parts;
+
+ /* Allocate space for holding the pair-wise join relations. */
+ joinrel->part_rels = (RelOptInfo **) palloc(sizeof(RelOptInfo *) *
+ nparts);
+ /* Create join relations for the partition relations. */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *part_join_rel;
+ part_join_rel = make_join_rel(root, rel1->part_rels[cnt_parts],
+ rel2->part_rels[cnt_parts]);
+ joinrel->part_rels[cnt_parts] = part_join_rel;
+ }
+
+ /* Add append paths for pair-wise joins. */
+ add_append_paths_to_joinrel(joinrel);
+ }
+
bms_free(joinrelids);
return joinrel;
}
+/*
+ * Given partitioin description of two joining relations, construct partition
+ * description for join between those relations.
+ *
+ * TODO find the right place for this function.
+ */
+static PartitionDesc
+build_joinrel_partition_desc(RelOptInfo *rel1, RelOptInfo *rel2,
+ SpecialJoinInfo *sjinfo)
+{
+ PartitionDesc part_desc;
+
+ /* Do nothing, if user doesn't want to try partition-wise join. */
+ if (!enable_partition_wise_join)
+ return NULL;
+
+ if (!are_partitions_joinable(rel1, rel2, sjinfo))
+ return NULL;
+
+ /*
+ * The result of join is partitioned the same way as the joining relations.
+ * Construct the partitioning scheme from the joining relations.
+ */
+ part_desc = (PartitionDesc) palloc0(sizeof(PartitionDescData));
+ part_desc->nparts = rel1->part_desc->nparts;
+ /* Fill up the rest of the fields. */
+
+ return part_desc;
+}
+
+/*
+ * Assess whether the given relations are similarly partitioned and have
+ * equi-join clauses on partition keys.
+ *
+ * Two relations are similarly partitioned if
+ * o. They have same number of partitions
+ * o. They have same number of partition keys*
+ * o. Partition keys have same types and opclasses*
+ * o. They have same upper and lower bounds (with inclusive/exclusive
+ * attributes) for all keys for range partitions. They have same list items for
+ * list partitions.
+ *
+ * Have same number of partition keys: It might be possible to join partitioned
+ * table which have different number of partition keys and suitable equi-join
+ * clauses to eliminate the possibilities. But right now, we do not consider
+ * this.
+ *
+ * Have same types and opclasses: Right now, we expect the partition keys to
+ * have exact same order of partion key types and opclasses. But it might
+ * be possible to relax this condition, if we can find which partition key
+ * matches which and also find corresponding equi-joins.
+ */
+static bool
+are_partitions_joinable(RelOptInfo *rel1, RelOptInfo *rel2,
+ SpecialJoinInfo *sjinfo)
+{
+ PartitionDesc part_desc1 = rel1->part_desc;
+ PartitionDesc part_desc2 = rel2->part_desc;
+
+ /* If either of the relations is not partitioned, nothing to check here. */
+ if (!part_desc1 || part_desc1->nparts == 0 ||
+ !part_desc2 || part_desc2->nparts == 0)
+ return false;
+
+ /*
+ * If the number of partitions on either side differs, partitioning schemes
+ * do not match.
+ * TODO: it should be possible to push an inner join down even if the number of
+ * partitions differ but the common partitions match. In such a case pushing
+ * down outer joins would be tricky, but still doable using empty relation
+ * for non-existing partition.
+ */
+ if (part_desc1->nparts != part_desc2->nparts)
+ return false;
+
+ /* TODO: */
+ /* All the artitions on either side should have same bounds or lists. */
+ /* Joining condition should have an equi-join on the partition key. */
+
+ /* By default, the partitions match. */
+ return true;
+}
+
+/*
+ * Add append paths for the join relation.
+ *
+ * Like set_append_rel_pathlist, this function considers pair-wise partition
+ * join paths with parameterization and pathkeys.
+ *
+ * TODO: right now the function just picks up the cheapest path from each of
+ * the partitions and creates an append path with those.
+ *
+ * TODO: may be we should consider splitting set_append_rel_pathlist() so that
+ * it can be used for both inheritance and partitioning.
+ */
+static void
+add_append_paths_to_joinrel(RelOptInfo *joinrel)
+{
+ RelOptInfo **part_rels = joinrel->part_rels;
+ int nparts;
+ int cnt_parts;
+ List *part_paths = NIL;
+
+ Assert(joinrel->part_desc);
+
+ nparts = joinrel->part_desc->nparts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *part_rel = part_rels[cnt_parts];
+
+ /* Find the cheapest path for partition relation. */
+ set_cheapest(part_rel);
+
+ /* We don't expect any parameterization here. */
+ Assert(!part_rel->cheapest_total_path->param_info);
+
+ /*
+ * Instead of lappend, we should use accumulate_append_subpath() to
+ * pull up the paths in underlying append.
+ */
+ part_paths = lappend(part_paths, part_rel->cheapest_total_path);
+ }
+
+ add_path(joinrel, (Path *) create_append_path(joinrel, part_paths, NULL,
+ 0));
+ return;
+}
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
* a join-order restriction arising from special or lateral joins.
*
* In practice this is always used with have_relevant_joinclause(), and so
* could be merged with that function, but it seems clearer to separate the
* two concerns. We need this test because there are degenerate cases where
* a clauseless join must be performed to satisfy join-order restrictions.
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 1179643..602f231 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -480,20 +480,35 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
{
rel->serverid = GetForeignServerIdByRelId(RelationGetRelid(relation));
rel->fdwroutine = GetFdwRoutineForRelation(relation, true);
}
else
{
rel->serverid = InvalidOid;
rel->fdwroutine = NULL;
}
+ /*
+ * Get the partitioning scheme.
+ * TODO: this is temporary code to stick partitioning information in
+ * RelOptInfo. We might change the way the information is stored. At every
+ * relation, we need to match partitioning information relevant at that
+ * level. So, storing only a single level partitioning information should
+ * suffice, even for a multi-level partitioned table.
+ */
+ rel->part_desc = RelationGetPartitionDesc(relation);
+ if (rel->part_desc && rel->part_desc->nparts > 0)
+ {
+ rel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) *
+ rel->part_desc->nparts);
+ }
+
heap_close(relation, NoLock);
/*
* Allow a plugin to editorialize on the info we obtained from the
* catalogs. Actions might include altering the assumed relation size,
* removing an index, or adding a hypothetical index to the indexlist.
*/
if (get_relation_info_hook)
(*get_relation_info_hook) (root, relationObjectId, inhparent, rel);
}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 1e87a73..6e7b1a4 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -377,25 +377,41 @@ build_join_rel(PlannerInfo *root,
* pair of component relations.
*/
if (restrictlist_ptr)
*restrictlist_ptr = build_joinrel_restrictlist(root,
joinrel,
outer_rel,
inner_rel);
return joinrel;
}
+ /* A partition relation can be joined with only partition relation. */
+ Assert(!(outer_rel->reloptkind == RELOPT_OTHER_JOINREL ||
+ outer_rel->reloptkind == RELOPT_OTHER_MEMBER_REL) ||
+ (inner_rel->reloptkind == RELOPT_OTHER_JOINREL ||
+ inner_rel->reloptkind == RELOPT_OTHER_MEMBER_REL));
+
/*
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
- joinrel->reloptkind = RELOPT_JOINREL;
+
+ /*
+ * A join between partitions or child tables is different from join between
+ * regular tables.
+ */
+ if (outer_rel->reloptkind == RELOPT_OTHER_JOINREL ||
+ outer_rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ else
+ joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
joinrel->consider_startup = (root->tuple_fraction > 0);
joinrel->consider_param_startup = false;
joinrel->consider_parallel = false;
joinrel->reltarget = create_empty_pathtarget();
joinrel->pathlist = NIL;
joinrel->ppilist = NIL;
joinrel->partial_pathlist = NIL;
@@ -539,21 +555,21 @@ build_join_rel(PlannerInfo *root,
Assert(!found);
hentry->join_rel = joinrel;
}
/*
* Also, if dynamic-programming join search is active, add the new joinrel
* to the appropriate sublist. Note: you might think the Assert on number
* of members should be for equality, but some of the level 1 rels might
* have been joinrels already, so we can only assert <=.
*/
- if (root->join_rel_level)
+ if (root->join_rel_level && joinrel->reloptkind != RELOPT_OTHER_JOINREL)
{
Assert(root->join_cur_level > 0);
Assert(root->join_cur_level <= bms_num_members(joinrel->relids));
root->join_rel_level[root->join_cur_level] =
lappend(root->join_rel_level[root->join_cur_level], joinrel);
}
return joinrel;
}
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index e246a9c..65e993e 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -879,20 +879,29 @@ static struct config_bool ConfigureNamesBool[] =
},
{
{"enable_fkey_estimates", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables use of foreign keys for estimating joins."),
NULL
},
&enable_fkey_estimates,
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
gettext_noop("Enables genetic query optimization."),
gettext_noop("This algorithm attempts to do planning without "
"exhaustive searching.")
},
&enable_geqo,
true,
NULL, NULL, NULL
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 45739c3..332e83f 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -12,20 +12,21 @@
*-------------------------------------------------------------------------
*/
#ifndef RELATION_H
#define RELATION_H
#include "access/sdir.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "storage/block.h"
+#include "catalog/partition.h"
/*
* Relids
* Set of relation identifiers (indexes into the rangetable).
*/
typedef Bitmapset *Relids;
/*
* When looking for a "cheapest path", this enum specifies whether we want
@@ -342,20 +343,27 @@ typedef struct PlannerInfo
* is present in the query join tree but the members are not. The member
* RTEs and otherrels are used to plan the scans of the individual tables or
* subqueries of the append set; then the parent baserel is given Append
* and/or MergeAppend paths comprising the best paths for the individual
* member rels. (See comments for AppendRelInfo for more information.)
*
* At one time we also made otherrels to represent join RTEs, for use in
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing each of the pair-wise joins between
+ * partitioned tables with same partitioning scheme. These relations are not
+ * added to join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm. Adding these two join_rel_level list also means that
+ * top level list has more than one join relation, which is symantically
+ * incorrect.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
* fields always hold Paths showing ways to do that processing step.
*
* Lastly, there is a RelOptKind for "dead" relations, which are base rels
* that we have proven we don't need to join after all.
*
* Parts of this data structure are specific to various scan and join
* mechanisms. It didn't seem worth creating new node types for them.
@@ -460,20 +468,21 @@ typedef struct PlannerInfo
* We store baserestrictcost in the RelOptInfo (for base relations) because
* we know we will need it at least once (to price the sequential scan)
* and may need it multiple times to price index scans.
*----------
*/
typedef enum RelOptKind
{
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
typedef struct RelOptInfo
{
NodeTag type;
RelOptKind reloptkind;
@@ -532,20 +541,35 @@ typedef struct RelOptInfo
struct FdwRoutine *fdwroutine;
void *fdw_private;
/* used by various scans and joins: */
List *baserestrictinfo; /* RestrictInfo structures (if base
* rel) */
QualCost baserestrictcost; /* cost of evaluating the above */
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations, joins or base relations. */
+ /* TODO: the partition hierarchy described by the members below, may be put
+ * into a path rather than RelOptInfo and will be handy in case we start
+ * supporting repartitioning of the data by different partitioning scheme.
+ *
+ * TODO: PartitionDescData contains the array of OIDs of the partitions, but that
+ * doesn't work for the partitions obtained by pair-wise joins of
+ * partitioned tables. We should probably create another data structure
+ * like AppendRelInfo for storing those, but I am not sure.
+ *
+ * TODO: Notice recursive usage of RelOptInfo.
+ */
+ PartitionDesc part_desc; /* Partitioning scheme if partitioned */
+ struct RelOptInfo **part_rels; /* RelOptInfo of the partitions. */
} RelOptInfo;
/*
* IndexOptInfo
* Per-index information for planning/optimization
*
* indexkeys[], indexcollations[], opfamily[], and opcintype[]
* each have ncolumns entries.
*
* sortopfamily[], reverse_sort[], and nulls_first[] likewise have
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 58ac163..ff2e3c7 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -60,20 +60,21 @@ extern bool enable_indexscan;
extern bool enable_indexonlyscan;
extern bool enable_bitmapscan;
extern bool enable_tidscan;
extern bool enable_sort;
extern bool enable_hashagg;
extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
extern bool enable_fkey_estimates;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
double index_pages, PlannerInfo *root);
extern void cost_seqscan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_samplescan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_index(IndexPath *path, PlannerInfo *root,
On Wed, Jun 15, 2016 at 3:25 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
Amit Langote is working on supporting declarative partitioning in PostgreSQL
[1]. I have started working on supporting partition-wise join. This mail
describes very high level design and some insight into the performance
improvements.An equi-join between two partitioned tables can be broken down into
pair-wise join between their partitions. This technique is called
partition-wise join. Partition-wise joins between similarly partitioned
tables with equi-join condition can be efficient because [2]
1. Each provably non-empty partition-wise join smaller. All such joins
collectively might be more efficient than the join between their parent.
2. Such joins are able to exploit properties of partitions like indexes,
their storage etc.
3. An N-way partition-wise join may have different efficient join orders
compared to the efficient join order between the parent tables.A partition-wise join is processed in following stages [2], [3].
1. Applicability testing: This phase checks if the join conditions match the
partitioning scheme. A partition-wise join is efficient if there is an
equi-join on the partition keys. E.g. join between tables R and S
partitioned by columns a and b resp. can be broken down into partition-wise
joins if there exists a join condition is R.a = S.b. Or in other words the
number of provably non-empty partition-wise joins is O(N) where N is the
number of partitions.2. Matching: This phase determines which joins between the partitions of R
and S can potentially produce tuples in the join and prunes empty joins
between partitions.3. Clustering: This phase aims at reducing the number of partition-wise
joins by clubbing together partitions from joining relations. E.g. clubbing
multiple partitions from either of the partitioned relations which can join
to a single partition from the other partitioned relation.4. Path/plan creation: This phase creates multiple paths for each
partition-wise join. It also creates Append path/s representing the union of
partition-wise joins.The work here focuses on a subset of use-cases discussed in [2]. It only
considers partition-wise join for join between similarly partitioned tables
with same number of partitions with same properties, thus producing at most
as many partition-wise joins as there are partitions. It should be possible
to apply partition-wise join technique (with some special handling for OUTER
joins) if both relations have some extra partitions with non-overlapping
partition conditions, apart from the matching partitions. But I am not
planning to implement this optimization in the first cut.
I haven't reviewed this code yet due to being busy with 9.6, but I
think this is a very important query planner improvement with the
potential for big wins on queries involving large amounts of data.
Suppose we have a pair of equi-partitioned tables. Right now, if we
choose to perform a hash join, we'll have to build a giant hash table
with all of the rows from every inner partition and then probe it for
every row in every outer partition. If there are few enough inner
rows that the resultant hash table still fits in work_mem, this is
somewhat inefficient but not terrible - but if it causes us to have to
batch the hash join where we otherwise would not need to do so, then
it really sucks. Similarly, if we decide to merge-join each pair of
partitions, a partitionwise join may be able to use an internal sort
on some or all partitions whereas if we had to deal with all of the
data at the same time we'd need an external sort, possibly multi-pass.
And if we choose a nested loop, say over an inner index-scan, we do
O(outer rows) index probes with this optimization but O(outer rows *
inner partitions) index probes without it.
In addition, parallel query can benefit significantly from this kind
of optimization. Tom recently raised the case of an appendrel where
every child has a parallel-safe path but not every child has a partial
path; currently, we can't go parallel in that case, but it's easy to
see that we could handle it by scheduling the appendrel's children
across a pool of workers. If we had this optimization, that sort of
thing would be much more likely to be useful, because it could create
appendrels where each member is an N-way join between equipartitioned
tables. That's particularly important right now because of the
restriction that a partial path must be driven by a Parallel SeqScan,
but even after that restriction is lifted it's easy to imagine that
the effective degree of parallelism for a single index scan may be
limited - so this kind of thing may significantly increase the number
of workers that a given query can use productively.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Fri, Jul 8, 2016 at 12:11 AM, Robert Haas <robertmhaas@gmail.com> wrote:
I haven't reviewed this code yet due to being busy with 9.6, but I
think this is a very important query planner improvement with the
potential for big wins on queries involving large amounts of data.Suppose we have a pair of equi-partitioned tables. Right now, if we
choose to perform a hash join, we'll have to build a giant hash table
with all of the rows from every inner partition and then probe it for
every row in every outer partition. If there are few enough inner
rows that the resultant hash table still fits in work_mem, this is
somewhat inefficient but not terrible - but if it causes us to have to
batch the hash join where we otherwise would not need to do so, then
it really sucks. Similarly, if we decide to merge-join each pair of
partitions, a partitionwise join may be able to use an internal sort
on some or all partitions whereas if we had to deal with all of the
data at the same time we'd need an external sort, possibly multi-pass.
Or we might be able to use indexes directly without need of a MergeAppend.
And if we choose a nested loop, say over an inner index-scan, we do
O(outer rows) index probes with this optimization but O(outer rows *
inner partitions) index probes without it.In addition, parallel query can benefit significantly from this kind
of optimization. Tom recently raised the case of an appendrel where
every child has a parallel-safe path but not every child has a partial
path; currently, we can't go parallel in that case, but it's easy to
see that we could handle it by scheduling the appendrel's children
across a pool of workers. If we had this optimization, that sort of
thing would be much more likely to be useful, because it could create
appendrels where each member is an N-way join between equipartitioned
tables. That's particularly important right now because of the
restriction that a partial path must be driven by a Parallel SeqScan,
but even after that restriction is lifted it's easy to imagine that
the effective degree of parallelism for a single index scan may be
limited - so this kind of thing may significantly increase the number
of workers that a given query can use productively.
+1.
The attached patch implements the logic to assess whether two partitioned
tables can be joined using partition-wise join technique described in my
last
mail on this thread.
Two partitioned relations are considered for partition-wise join if
following
conditions are met (See build_joinrel_part_info() for details):
1. Both the partitions have same number of partitions, with same number of
partition keys and partitioned by same strategy - range or list.
2. They have matching datatypes for partition keys (partkey_types_match())
3. For list partitioned relations, they have same lists for each pair of
partitions, paired by position in which they appear.
4. For range partitioned relations, they have same bounds for each pair of
partitions, paired by their position when ordered in ascending fashion on
the
upper bounds.
5. There exists an equi-join condition for each pair of partition keys,
paired
by the position in which they appear.
Partition-wise join technique can be applied under more lenient constraints
[1]: e.g. joins between tables with different number of partitions but having same bounds/lists for the common partitions. I am planning to defer that to a later version of this feature.
e.g. joins between tables with different number of partitions but having
same
bounds/lists for the common partitions. I am planning to defer that to a
later
version of this feature.
A join executed using partition-wise join technique is itself a relation
partitioned by the similar partitioning scheme as the joining relations with
the partition keys combined from the joining relations.
A PartitionOptInfo (uses name similar to RelOptInfo or IndexOptInfo)
structure
is used to store the partitioning information for a given base or relation.
In build_simple_rel(), we construct PartitionOptInfo structure for the given
base relation by copying the relation's PartitionDesc and PartitionKey
(structures from Amit Langote's patch). While doing so, all the partition
keys
are stored as expressions. The structure also holds the RelOptInfos of the
partition relations. For a join relation, most of the PartitionOptInfo is
copied from either of the joining relations, except the partition keys and
RelOptInfo of partition relations. Partition keys of the join relations are
created by combing partition keys from both the joining relations. The
logic to
cosnstruct RelOptInfo for the partition-wise join relations is yet to be
implemented.
Since the logic to create the paths and RelOptInfos for partition-wise join
relations is not implemented yet, a query which can use partition-wise join
fails with error
"ERROR: the relation was considered for partition-wise join, which is not
supported right now.". It will also print messages to show which of the
joins
can and can not use partition-wise join technique e.g.
"NOTICE: join between relations (b 1) and (b 2) is considered for
partition-wise join." The relations are indicated by their relid in the
query.
OR
"NOTICE: join between relations (b 1) and (b 2) is NOT considered for
partition-wise join.".
These messages are for debugging only, and will be removed once path
creation
logic is implemented.
The patch adds a test partition_join.sql, which has a number of positive and
negative testcases for joins between partitioned tables.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_assess_phase.patchapplication/x-download; name=pg_dp_join_assess_phase.patchDownload
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 2e4b670..06fc90d 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -999,21 +999,59 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
if (rel->has_eclass_joins || has_useful_pathkeys(root, rel))
add_child_rel_equivalences(root, appinfo, rel, childrel);
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
* Note: we could compute appropriate attr_needed data for the child's
* variables, by transforming the parent's attr_needed through the
* translated_vars mapping. However, currently there's no need
* because attr_needed is only examined for base relations not
* otherrels. So we just leave the child's attr_needed empty.
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for building pair-wise
+ * join relations. Partitions should have same layout as the parent
+ * table and hence should not need any translation, but we still use
+ * the translated_vars to keep the code in sync with the inheritance
+ * code.
*/
+ if (rel->part_info)
+ {
+ AttrNumber attno;
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /* Parent Var translates to child Var. */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
+ }
/*
* Compute the child's size.
*/
set_rel_size(root, childrel, childRTindex, childRTE);
/*
* It is possible that constraint exclusion detected a contradiction
* within a child subquery, even though we didn't prove one above. If
* so, we can skip this child.
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 8c1dccc..3ab6a9d 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -119,20 +119,21 @@ bool enable_seqscan = true;
bool enable_indexscan = true;
bool enable_indexonlyscan = true;
bool enable_bitmapscan = true;
bool enable_tidscan = true;
bool enable_sort = true;
bool enable_hashagg = true;
bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
typedef struct
{
PlannerInfo *root;
QualCost total;
} cost_qual_eval_context;
static List *extract_nonindex_conditions(List *qual_clauses, List *indexquals);
static MergeScanSelCache *cached_scansel(PlannerInfo *root,
RestrictInfo *rinfo,
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..e485e01 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -7,38 +7,56 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* src/backend/optimizer/path/joinrels.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
static void make_rels_by_clause_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static void make_rels_by_clauseless_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static PartitionOptInfo *build_joinrel_part_info(RelOptInfo *rel1,
+ RelOptInfo *rel2, SpecialJoinInfo *sjinfo,
+ List *restrictlist);
+static void add_append_paths_to_joinrel(RelOptInfo *joinrel);
+static void match_expr_to_partition_keys(RestrictInfo *rinfo, Expr *expr,
+ RelOptInfo *rel, List **pkclauses);
+static bool partkey_types_match(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2);
+static bool have_same_partition_lists(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2);
+static bool have_same_partition_bounds(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2);
+static bool compare_partition_bounds(PartitionOptInfo *part_info,
+ PartitionRangeBound *bound1, PartitionRangeBound *bound2);
/*
* join_search_one_level
* Consider ways to produce join relations containing exactly 'level'
* jointree items. (This is one step of the dynamic-programming method
* embodied in standard_join_search.) Join rel nodes for each feasible
* combination of lower-level rels are created and returned in a list.
* Implementation paths are created for each such joinrel, too.
*
@@ -652,20 +670,21 @@ join_is_legal(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
*/
RelOptInfo *
make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
{
Relids joinrelids;
SpecialJoinInfo *sjinfo;
bool reversed;
SpecialJoinInfo sjinfo_data;
RelOptInfo *joinrel;
List *restrictlist;
+ PartitionOptInfo *part_info;
/* We should never try to join two overlapping sets of rels. */
Assert(!bms_overlap(rel1->relids, rel2->relids));
/* Construct Relids set that identifies the joinrel. */
joinrelids = bms_union(rel1->relids, rel2->relids);
/* Check validity and determine join type. */
if (!join_is_legal(root, rel1, rel2, joinrelids,
&sjinfo, &reversed))
@@ -862,25 +881,372 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
break;
default:
/* other values not expected here */
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
+ /*
+ * If both the relations are partitioned in the same way, and there is an
+ * equi-join clause on partition key, try joining the partitions. Store the
+ * partitioning scheme in joinrel for further joins.
+ */
+ part_info = build_joinrel_part_info(rel1, rel2, sjinfo, restrictlist);
+ joinrel->part_info = part_info;
+ if (part_info)
+ {
+ PartitionOptInfo *part_info1 = rel1->part_info;
+ PartitionOptInfo *part_info2 = rel2->part_info;
+ int nparts = part_info->nparts;
+ int cnt_parts;
+ StringInfo rel1_desc = makeStringInfo();
+ StringInfo rel2_desc = makeStringInfo();
+
+ /* TODO: remove this notice when finalising the patch. */
+ outBitmapset(rel1_desc, rel1->relids);
+ outBitmapset(rel2_desc, rel2->relids);
+ elog(NOTICE, "join between relations %s and %s is considered for partition-wise join.",
+ rel1_desc->data, rel2_desc->data);
+
+ /* Create join relations for the partition relations. */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *part_join_rel;
+
+ /*
+ * TODO: make_join_rel can return NULL if the join is illegal. This
+ * should not happen since the join between parents is deemed
+ * legal.
+ */
+ part_join_rel = make_join_rel(root,
+ part_info1->part_rels[cnt_parts],
+ part_info2->part_rels[cnt_parts]);
+ part_info->part_rels[cnt_parts] = part_join_rel;
+ }
+
+ /* Add append paths for pair-wise joins. */
+ add_append_paths_to_joinrel(joinrel);
+ }
+ /* TODO: remove this notice printing code while finalising the patch. */
+ else if (!IS_OTHER_REL(rel1->reloptkind) && !IS_OTHER_REL(rel2->reloptkind))
+ {
+ StringInfo rel1_desc = makeStringInfo();
+ StringInfo rel2_desc = makeStringInfo();
+
+ /* TODO: remove this notice when finalising the patch. */
+ outBitmapset(rel1_desc, rel1->relids);
+ outBitmapset(rel2_desc, rel2->relids);
+ elog(NOTICE, "join between relations %s and %s is NOT considered for partition-wise join.",
+ rel1_desc->data, rel2_desc->data);
+ }
+
bms_free(joinrelids);
return joinrel;
}
+/*
+ * build_joinrel_part_info
+ *
+ * Given partition description of two joining relations, construct partition
+ * description for join between those relations. If we can execute
+ * partition-wise join the resultant join is partitioned in the same way as the
+ * joining relations. Otherwise, it is not partitioned and in such case the
+ * function returns NULL.
+ *
+ * TODO find the right place for this function.
+ *
+ * TODO:
+ * This function and
+ * build_partition_info() should be named consistently e.g.
+ * build_joinrel_partition_info and build_simplerel_partition_info or
+ * build_baserel_partition_info resp.
+ */
+static PartitionOptInfo *
+build_joinrel_part_info(RelOptInfo *rel1, RelOptInfo *rel2,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
+ PartitionOptInfo *part_info;
+ PartitionOptInfo *part_info1 = rel1->part_info;
+ PartitionOptInfo *part_info2 = rel2->part_info;
+ int cnt_pks;
+ int num_pks;
+
+ /* Do nothing, if user doesn't want to try partition-wise join. */
+ if (!enable_partition_wise_join)
+ return NULL;
+
+ /*
+ * If number of partitions, number of partition keys and partitioning
+ * strategy of the joining relations do not match, we can not apply
+ * partition-wise join.
+ *
+ * TODO: it should be possible to push an inner join down even if the number of
+ * partitions differ but the common partitions match. In such a case pushing
+ * down outer joins would be tricky, but still doable using empty relation
+ * for non-existing partition.
+ */
+ if (!part_info1 || !part_info2 ||
+ part_info1->nparts != part_info2->nparts ||
+ part_info1->strategy != part_info2->strategy ||
+ part_info1->partnatts != part_info2->partnatts)
+ return NULL;
+
+ /*
+ * Partition-wise join can not be applied if datatypes and collations of
+ * the partition keys do not match.
+ */
+ if (!partkey_types_match(part_info1, part_info2))
+ return NULL;
+
+ /*
+ * Partition-wise join can not be applied if the partition bounds or lists
+ * of joining relations do not match.
+ */
+ switch (part_info1->strategy)
+ {
+ case PARTITION_STRAT_LIST:
+ if (!have_same_partition_lists(part_info1, part_info2))
+ return NULL;
+ break;
+
+ case PARTITION_STRAT_RANGE:
+ if (!have_same_partition_bounds(part_info1, part_info2))
+ return NULL;
+ break;
+
+ default:
+ /* Unknown partition strategy. */
+ return NULL;
+ }
+
+ /*
+ * Partition-wise join can not be applied if there is no equi-join
+ * condition between partition keys.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, sjinfo, restrictlist))
+ return NULL;
+
+ /* The join is partitioned the similar to the joining relations. */
+ part_info = makeNode(PartitionOptInfo);
+
+ /* Information related to the partititions. */
+ part_info->nparts = part_info1->nparts;
+ /* Allocate space for partition RelOptInfos, which will be filled later. */
+ part_info->part_rels = (RelOptInfo **) palloc(sizeof(RelOptInfo *) *
+ part_info->nparts);
+ part_info->lists = part_info1->lists;
+ part_info->rangelowers = part_info1->rangelowers;
+ part_info->rangeuppers = part_info1->rangeuppers;
+
+ /* Information related to partition keys. */
+ part_info->strategy = part_info1->strategy;
+ part_info->partnatts = part_info1->partnatts;
+ part_info->partopfamily = part_info1->partopfamily;
+ part_info->partopcintype = part_info1->partopcintype;
+ part_info->partsupfunc = part_info1->partsupfunc;
+ part_info->tcinfo = part_info1->tcinfo;
+ num_pks = part_info->partnatts;
+ part_info->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexpr = list_copy(part_info1->partexprs[cnt_pks]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(part_info2->partexprs[cnt_pks]));
+ part_info->partexprs[cnt_pks] = pkexpr;
+ }
+
+ return part_info;
+}
+
+/*
+ * Returns true if the given relations have equi-join clauses on all the
+ * corresponding partition keys.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
+ PartitionOptInfo *part_info1 = rel1->part_info;
+ PartitionOptInfo *part_info2 = rel2->part_info;
+ ListCell *lc;
+ List **pkclauses1;
+ List **pkclauses2;
+ int cnt_pks;
+ int num_pks;
+
+ Assert(part_info1->partnatts == part_info2->partnatts);
+ num_pks = part_info1->partnatts;
+ pkclauses1 = (List **) palloc0(sizeof(List *) * num_pks);
+ pkclauses2 = (List **) palloc0(sizeof(List *) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(sjinfo->jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip non-equi-join clauses. */
+ if (!rinfo->can_join ||
+ rinfo->hashjoinoperator == InvalidOid ||
+ !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+ /*
+ * If clause of form rel1_expr op rel2_expr OR rel2_expr op rel1_expr,
+ * match the operands to the relations. Otherwise, the clause is
+ * not an equi-join between partition keys of joining relations.
+ */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ match_expr_to_partition_keys(rinfo, expr1, rel1, pkclauses1);
+ match_expr_to_partition_keys(rinfo, expr2, rel2, pkclauses2);
+ }
+
+ /*
+ * If every pair of partition key from either of the joining relation has
+ * at least one equi-join clause associated with it, we have an equi-join
+ * between all corresponding partition keys.
+ */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *li = list_intersection(pkclauses1[cnt_pks],
+ pkclauses2[cnt_pks]);
+ if (!li)
+ return false;
+
+ /* We don't need the actual intersection list. */
+ list_free(li);
+ }
+ return true;
+}
+
+/*
+ * match_expr_to_partition_keys
+ *
+ * Find the partition key which is same as the given expression. If we are able
+ * to find one, add the clause to the list of clauses associated with that
+ * partition key. It is assumed that the given expression is part of the given
+ * clause.
+ *
+ * TODO: Since a given partition key appears only once in the partition by
+ * clause, it should be possible to return the position of the matching
+ * partition key and let the caller handle association of clauses. If we do so,
+ * we will be able to discard the clauses associated with different partition
+ * keys and just remember whether a pair of partition keys has associated
+ * clause or not (rather than remembering the whole list of clauses).
+ */
+static void
+match_expr_to_partition_keys(RestrictInfo *rinfo, Expr *expr, RelOptInfo *rel,
+ List **pkclauses)
+{
+ PartitionOptInfo *part_info = rel->part_info;
+ int cnt_pks;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() will have simplied if more
+ * than one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < part_info->partnatts; cnt_pks++)
+ {
+ List *pkexprs = part_info->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ {
+ pkclauses[cnt_pks] = list_append_unique(pkclauses[cnt_pks],
+ rinfo);
+ break;
+ }
+ }
+ }
+}
+
+/*
+ * Add append paths for the join relation.
+ *
+ * Like set_append_rel_pathlist, this function considers pair-wise partition
+ * join paths with parameterization and pathkeys.
+ *
+ * TODO: right now the function just picks up the cheapest path from each of
+ * the partitions and creates an append path with those.
+ *
+ * TODO: may be we should consider splitting set_append_rel_pathlist() so that
+ * it can be used for both inheritance and partitioning.
+ */
+static void
+add_append_paths_to_joinrel(RelOptInfo *joinrel)
+{
+ PartitionOptInfo *part_info = joinrel->part_info;
+ RelOptInfo **part_rels = part_info->part_rels;
+ int nparts;
+ int cnt_parts;
+ List *part_paths = NIL;
+
+ Assert(part_info);
+
+ nparts = part_info->nparts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *part_rel = part_rels[cnt_parts];
+
+ /* Find the cheapest path for partition relation. */
+ set_cheapest(part_rel);
+
+ /* We don't expect any parameterization here. */
+ Assert(!part_rel->cheapest_total_path->param_info);
+
+ /*
+ * Instead of lappend, we should use accumulate_append_subpath() to
+ * pull up the paths in underlying append.
+ */
+ part_paths = lappend(part_paths, part_rel->cheapest_total_path);
+ }
+
+ add_path(joinrel, (Path *) create_append_path(joinrel, part_paths, NULL,
+ 0));
+ return;
+}
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
* a join-order restriction arising from special or lateral joins.
*
* In practice this is always used with have_relevant_joinclause(), and so
* could be merged with that function, but it seems clearer to separate the
* two concerns. We need this test because there are degenerate cases where
* a clauseless join must be performed to satisfy join-order restrictions.
@@ -1242,10 +1608,180 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
/* constant NULL is as good as constant FALSE for our purposes */
if (con->constisnull)
return true;
if (!DatumGetBool(con->constvalue))
return true;
}
}
return false;
}
+
+/*
+ * have_same_partition_lists
+ *
+ * For given list partitioned relations, return true if lists for all the
+ * partitions of both the relations match. Return false otherwise.
+ */
+static bool
+have_same_partition_lists(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2)
+{
+ int cnt_parts;
+
+ Assert(part_info1->strategy == PARTITION_STRAT_LIST &&
+ part_info2->strategy == PARTITION_STRAT_LIST);
+
+ Assert(part_info1->nparts == part_info2->nparts);
+
+ /* List partition has only one partition key. */
+ Assert(part_info1->partnatts == 1 && part_info2->partnatts == 1);
+
+ for (cnt_parts = 0; cnt_parts < part_info1->nparts; cnt_parts++)
+ {
+ PartitionListBound *list1 = part_info1->lists[cnt_parts];
+ PartitionListBound *list2 = part_info2->lists[cnt_parts];
+ int cnt;
+
+ /*
+ * If number of items in the lists do not match or the one of the lists
+ * contains NULL value and other doesn't, lists do not match.
+ *
+ * TODO: This condition can be relaxed to accomodate subset of items,
+ * but probably not in the first cut.
+ */
+ if (list1->contains_null != list2->contains_null ||
+ list1->nvalues != list2->nvalues)
+ return false;
+
+ /* Compare actual values in the list. */
+ for (cnt = 0; cnt < list1->nvalues; cnt++)
+ {
+ Datum cmpval;
+
+ cmpval = FunctionCall2Coll(&part_info1->partsupfunc[0],
+ part_info1->tcinfo->typcoll[0],
+ list1->values[cnt],
+ list2->values[cnt]);
+ if (DatumGetInt32(cmpval))
+ return false;
+ }
+ }
+
+ /* Ok, everything matches, return true. */
+ return true;
+}
+
+/*
+ * have_same_partition_bounds
+ *
+ * For given partitioned relations, return true if the bounds of all the
+ * partitions of the both the relations match. Return false otherwise.
+ */
+static bool
+have_same_partition_bounds(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2)
+{
+ int cnt_parts;
+ Assert(part_info1->strategy == PARTITION_STRAT_RANGE &&
+ part_info2->strategy == PARTITION_STRAT_RANGE);
+
+ Assert(part_info1->nparts == part_info2->nparts);
+
+ for (cnt_parts = 0; cnt_parts < part_info1->nparts; cnt_parts++)
+ {
+ PartitionRangeBound *lower1 = part_info1->rangelowers[cnt_parts];
+ PartitionRangeBound *lower2 = part_info2->rangelowers[cnt_parts];
+ PartitionRangeBound *upper1 = part_info1->rangeuppers[cnt_parts];
+ PartitionRangeBound *upper2 = part_info2->rangeuppers[cnt_parts];
+
+ if (!compare_partition_bounds(part_info1, lower1, lower2) ||
+ !compare_partition_bounds(part_info1, upper1, upper2))
+ return false;
+ }
+
+ /* Ok, everything matches. */
+ return true;
+}
+
+/*
+ * compare_partition_bounds
+ *
+ * Return true if given bound specifications match.
+ */
+static bool
+compare_partition_bounds(PartitionOptInfo *part_info,
+ PartitionRangeBound *bound1,
+ PartitionRangeBound *bound2)
+{
+ int cnt_pks;
+ Datum *val1 = bound1->val;
+ Datum *val2 = bound2->val;
+
+ if (bound1->infinite != bound2->infinite ||
+ bound1->inclusive != bound2->inclusive ||
+ bound1->lower != bound2->lower)
+ return false;
+
+ /*
+ * TODO:
+ * Following part is common with compare_range_keys(), but that takes
+ * PartitionKey as argument, which we don't have here.
+ */
+ for (cnt_pks = 0; cnt_pks < part_info->partnatts; cnt_pks++)
+ {
+ Datum cmpval;
+
+ cmpval = FunctionCall2Coll(&part_info->partsupfunc[cnt_pks],
+ part_info->tcinfo->typcoll[cnt_pks],
+ val1[cnt_pks], val2[cnt_pks]);
+
+ if (DatumGetInt32(cmpval))
+ return false;
+ }
+
+ /* Ok, everything matches. */
+ return true;
+}
+
+/*
+ * partkey_types_match
+ *
+ * Returns true if the partition key datatype and collation match for given
+ * partitioned relations. Returns false otherwise.
+ */
+static bool
+partkey_types_match(PartitionOptInfo *part_info1, PartitionOptInfo *part_info2)
+{
+ int cnt_pks;
+ Oid *partopfamily1 = part_info1->partopfamily;
+ Oid *partopfamily2 = part_info2->partopfamily;
+ Oid *partopcintype1 = part_info1->partopcintype;
+ Oid *partopcintype2 = part_info2->partopcintype;
+ FmgrInfo *partsupfunc1 = part_info1->partsupfunc;
+ FmgrInfo *partsupfunc2 = part_info2->partsupfunc;
+ KeyTypeCollInfo *tcinfo1 = part_info1->tcinfo;
+ KeyTypeCollInfo *tcinfo2 = part_info2->tcinfo;
+
+ if (part_info1->partnatts != part_info1->partnatts)
+ return false;
+
+ for (cnt_pks = 0; cnt_pks < part_info1->partnatts; cnt_pks++)
+ {
+ /*
+ * It suffices to check the OID of support function as it always has
+ * two arguemnts and returns boolean. For types, it suffices to match
+ * the type id, mod and collation; len, byval and align are depedent on
+ * the first two.
+ */
+ if (partopfamily1[cnt_pks] != partopfamily2[cnt_pks] ||
+ partopcintype1[cnt_pks] != partopcintype2[cnt_pks] ||
+ partsupfunc1[cnt_pks].fn_oid != partsupfunc2[cnt_pks].fn_oid ||
+ tcinfo1->typid[cnt_pks] != tcinfo2->typid[cnt_pks] ||
+ tcinfo1->typmod[cnt_pks] != tcinfo2->typmod[cnt_pks] ||
+ tcinfo1->typcoll[cnt_pks] != tcinfo2->typcoll[cnt_pks])
+ return false;
+ }
+
+ /* Everything matches. */
+ return true;
+}
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 9e5b60e..6cd8d8c 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -339,20 +339,25 @@ create_plan(PlannerInfo *root, Path *best_path)
/*
* create_plan_recurse
* Recursive guts of create_plan().
*/
static Plan *
create_plan_recurse(PlannerInfo *root, Path *best_path, int flags)
{
Plan *plan;
+ /* TODO: remove this code to continue partition-wise join planning. */
+ if (best_path->parent->reloptkind == RELOPT_JOINREL &&
+ best_path->parent->part_info)
+ elog(ERROR, "the relation was considered for partition-wise join, which is not supported right now.");
+
switch (best_path->pathtype)
{
case T_SeqScan:
case T_SampleScan:
case T_IndexScan:
case T_IndexOnlyScan:
case T_BitmapHeapScan:
case T_TidScan:
case T_SubqueryScan:
case T_FunctionScan:
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 95aca08..739ce3d 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -1202,21 +1202,28 @@ get_relation_constraints(PlannerInfo *root,
ntest->nulltesttype = IS_NOT_NULL;
ntest->argisrow = type_is_rowtype(att->atttypid);
ntest->location = -1;
result = lappend(result, ntest);
}
}
}
}
/* Append partition check quals, if any */
- pcqual = RelationGetPartitionCheckQual(relation);
+ /*
+ * TODO the copyObject wrapper has been added by me to avoid changing
+ * partitioned copy of cache. This should be fixed by Amit in his original
+ * patches and mostly in get_check_qual_for_range() or
+ * get_relation_constraints(). Once it's fixed their, remove the copyObject
+ * wrapper.
+ */
+ pcqual = copyObject(RelationGetPartitionCheckQual(relation));
if (pcqual)
{
/* Fix Vars to have the desired varno */
if (varno != 1)
ChangeVarNodes((Node *) pcqual, 1, varno, 0);
result = list_concat(result, pcqual);
}
heap_close(relation, NoLock);
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index a0a284b..b310c4d 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -8,31 +8,35 @@
*
*
* IDENTIFICATION
* src/backend/optimizer/util/relnode.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
#include "catalog/pg_class.h"
#include "foreign/foreign.h"
+#include "nodes/makefuncs.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
{
Relids join_relids; /* hash key --- MUST BE FIRST */
RelOptInfo *join_rel;
} JoinHashEntry;
static void build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel);
@@ -42,20 +46,22 @@ static List *build_joinrel_restrictlist(PlannerInfo *root,
RelOptInfo *inner_rel);
static void build_joinrel_joinlist(RelOptInfo *joinrel,
RelOptInfo *outer_rel,
RelOptInfo *inner_rel);
static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_restrictlist);
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static PartitionOptInfo *build_partition_info(PlannerInfo *root,
+ RelOptInfo *rel);
/*
* setup_simple_rel_arrays
* Prepare the arrays we use for quickly accessing base relations.
*/
void
setup_simple_rel_arrays(PlannerInfo *root)
{
Index rti;
@@ -190,27 +196,33 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
userid = OidIsValid(rte->checkAsUser) ? rte->checkAsUser : GetUserId();
rel->umid = GetUserMappingId(userid, rel->serverid, true);
}
else
rel->umid = InvalidOid;
/* Save the finished struct in the query's simple_rel_array */
root->simple_rel_array[relid] = rel;
+ /* Get the partitioning information, if any. */
+ if (rte->rtekind == RTE_RELATION)
+ rel->part_info = build_partition_info(root, rel);
+ else
+ rel->part_info = NULL;
+
/*
- * If this rel is an appendrel parent, recurse to build "other rel"
- * RelOptInfos for its children. They are "other rels" because they are
- * not in the main join tree, but we will need RelOptInfos to plan access
- * to them.
+ * If this rel is an unpartitioned appendrel parent, recurse to build
+ * "other rel" RelOptInfos for its children. They are "other rels" because
+ * they are not in the main join tree, but we will need RelOptInfos to plan
+ * access to them.
*/
- if (rte->inh)
+ if (!rel->part_info && rte->inh)
{
ListCell *l;
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != relid)
continue;
@@ -381,21 +393,34 @@ build_join_rel(PlannerInfo *root,
joinrel,
outer_rel,
inner_rel);
return joinrel;
}
/*
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
- joinrel->reloptkind = RELOPT_JOINREL;
+
+ /*
+ * A join between partitions or child tables is different from join between
+ * regular tables.
+ */
+ if (IS_OTHER_REL(outer_rel->reloptkind))
+ {
+ /* A partition table can be joined only with other partition table. */
+ Assert(IS_OTHER_REL(inner_rel->reloptkind));
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ }
+ else
+ joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
joinrel->consider_startup = (root->tuple_fraction > 0);
joinrel->consider_param_startup = false;
joinrel->consider_parallel = false;
joinrel->reltarget = create_empty_pathtarget();
joinrel->pathlist = NIL;
joinrel->ppilist = NIL;
joinrel->partial_pathlist = NIL;
@@ -540,21 +565,21 @@ build_join_rel(PlannerInfo *root,
Assert(!found);
hentry->join_rel = joinrel;
}
/*
* Also, if dynamic-programming join search is active, add the new joinrel
* to the appropriate sublist. Note: you might think the Assert on number
* of members should be for equality, but some of the level 1 rels might
* have been joinrels already, so we can only assert <=.
*/
- if (root->join_rel_level)
+ if (root->join_rel_level && joinrel->reloptkind != RELOPT_OTHER_JOINREL)
{
Assert(root->join_cur_level > 0);
Assert(root->join_cur_level <= bms_num_members(joinrel->relids));
root->join_rel_level[root->join_cur_level] =
lappend(root->join_rel_level[root->join_cur_level], joinrel);
}
return joinrel;
}
@@ -1317,10 +1342,179 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
ppi->ppi_req_outer = required_outer;
ppi->ppi_rows = 0;
ppi->ppi_clauses = NIL;
appendrel->ppilist = lappend(appendrel->ppilist, ppi);
return ppi;
}
+
+/*
+ * build_partition_info
+ *
+ * Retrieves partitioning information for given relation.
+ *
+ * The function also builds the RelOptInfos of the partitions recursively.
+ * TODO: complete the prologue.
+ */
+static PartitionOptInfo *
+build_partition_info(PlannerInfo *root, RelOptInfo *rel)
+{
+ Relation relation;
+ PartitionKey part_key;
+ PartitionDesc part_desc;
+ PartitionOptInfo *part_info;
+ RangeTblEntry *rte;
+ ListCell *lc;
+ int num_pkexprs;
+ int cnt_pke;
+ int cnt_parts;
+ Expr *pkexpr;
+ Index top_parent_relid;
+
+ /* The given relation should be simple relation. */
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ Assert(rel->relid != 0);
+
+ rte = root->simple_rte_array[rel->relid];
+ Assert(rte);
+
+ /*
+ * For multi-level partitioned tables the children themselves can be
+ * partitioned. In such a case, partitions at higher levels will have
+ * parent relid of the topmost relation.
+ */
+ if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ {
+ RelOptInfo *parent_rel = find_childrel_top_parent(root, rel);
+ RangeTblEntry *parent_rte;
+
+ top_parent_relid = parent_rel->relid;
+ parent_rte = root->simple_rte_array[top_parent_relid];
+
+ /*
+ * A relation appearing in its own partition hierarchy does not have
+ * PartitionOptInfo in its RelOptInfo, lest it creates recursively
+ * infinite chain of RelOptInfos and PartitionOptInfos.
+ */
+ if (parent_rte->relid == rte->relid)
+ return NULL;
+ }
+ else
+ top_parent_relid = rel->relid;
+
+ /*
+ * We need not lock the relation since it was already locked, either
+ * by the rewriter or when expand_inherited_rtentry() added it to
+ * the query's rangetable.
+ */
+ relation = heap_open(rte->relid, NoLock);
+ part_desc = RelationGetPartitionDesc(relation);
+ part_key = RelationGetPartitionKey(relation);
+
+ /* Nothing to do for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ {
+ heap_close(relation, NoLock);
+ return NULL;
+ }
+
+ part_info = makeNode(PartitionOptInfo);
+
+ /* Store partition descriptor information. */
+ part_info->nparts = part_desc->nparts;
+ /* TODO: Should we copy the contents of the these arrays? */
+ part_info->lists = part_desc->lists;
+ part_info->rangelowers = part_desc->rangelowers;
+ part_info->rangeuppers = part_desc->rangeuppers;
+
+ /* Store partition key information. */
+ part_info->strategy = part_key->strategy;
+ part_info->partnatts = part_key->partnatts;
+ num_pkexprs = part_info->partnatts;
+ /* TODO: Should we copy the contents of these arrays? */
+ part_info->partopfamily = part_key->partopfamily;
+ part_info->partopcintype = part_key->partopcintype;
+ part_info->partsupfunc = part_key->partsupfunc;
+ part_info->tcinfo = part_key->tcinfo;
+
+ /* Store partition keys as single elements lists. */
+ part_info->partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(rel->relid, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (!lc)
+ elog(ERROR, "wrong number of partition key expressions");
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, rel->relid, 0);
+ lc = lnext(lc);
+ }
+
+ part_info->partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ /* Find RelOptInfo of the partitions. */
+ part_info->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) *
+ part_info->nparts);
+ foreach(lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(lc);
+ int childRTindex = appinfo->child_relid;
+ RangeTblEntry *childRTE = root->simple_rte_array[childRTindex];
+ RelOptInfo *childrel = root->simple_rel_array[childRTindex];
+
+ /* append_rel_list contains all append rels; ignore others */
+ if (appinfo->parent_relid != top_parent_relid)
+ continue;
+
+ /* If we haven't created a RelOptInfo aleady, create one. */
+ if (!childrel)
+ childrel = build_simple_rel(root, childRTindex,
+ RELOPT_OTHER_MEMBER_REL);
+ /*
+ * OIDs of the partitions are arranged to match the partition bounds or
+ * list in corresponding arrays. Arrange RelOptInfo's of partitions in
+ * the same fashion.
+ */
+ for (cnt_parts = 0; cnt_parts < part_info->nparts; cnt_parts++)
+ {
+ if (part_desc->oids[cnt_parts] == childRTE->relid)
+ {
+ /* Every partition can be seen only once. */
+ Assert(!part_info->part_rels[cnt_parts]);
+ part_info->part_rels[cnt_parts] = childrel;
+
+ break;
+ }
+ }
+ }
+
+ heap_close(relation, NoLock);
+
+ /* We must have found RelOptInfos of all the partitions. */
+ for (cnt_parts = 0; cnt_parts < part_info->nparts; cnt_parts++)
+ Assert(part_info->part_rels[cnt_parts]);
+
+ return part_info;
+}
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 60148b8..2beb0ec 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -870,20 +870,29 @@ static struct config_bool ConfigureNamesBool[] =
},
{
{"enable_hashjoin", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of hash join plans."),
NULL
},
&enable_hashjoin,
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
gettext_noop("Enables genetic query optimization."),
gettext_noop("This algorithm attempts to do planning without "
"exhaustive searching.")
},
&enable_geqo,
true,
NULL, NULL, NULL
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 365073b..b17de61 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -217,20 +217,21 @@ typedef enum NodeTag
T_DomainConstraintState,
/*
* TAGS FOR PLANNER NODES (relation.h)
*/
T_PlannerInfo = 500,
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
T_ForeignKeyOptInfo,
+ T_PartitionOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
T_BitmapHeapPath,
T_BitmapAndPath,
T_BitmapOrPath,
T_TidPath,
T_SubqueryScanPath,
T_ForeignPath,
T_CustomPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 0b5cb9e..bffd312 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -12,20 +12,21 @@
*-------------------------------------------------------------------------
*/
#ifndef RELATION_H
#define RELATION_H
#include "access/sdir.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "storage/block.h"
+#include "catalog/partition.h"
/*
* Relids
* Set of relation identifiers (indexes into the rangetable).
*/
typedef Bitmapset *Relids;
/*
* When looking for a "cheapest path", this enum specifies whether we want
@@ -347,20 +348,26 @@ typedef struct PlannerInfo
* is present in the query join tree but the members are not. The member
* RTEs and otherrels are used to plan the scans of the individual tables or
* subqueries of the append set; then the parent baserel is given Append
* and/or MergeAppend paths comprising the best paths for the individual
* member rels. (See comments for AppendRelInfo for more information.)
*
* At one time we also made otherrels to represent join RTEs, for use in
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing pair-wise joins between partitions of
+ * partitioned tables. These relations are not added to join_rel_level lists
+ * as they are not joined directly by the dynamic programming algorithm.
+ * Adding these two join_rel_level list also means that top level list has more
+ * than one join relation, which is symantically incorrect.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
* fields always hold Paths showing ways to do that processing step.
*
* Lastly, there is a RelOptKind for "dead" relations, which are base rels
* that we have proven we don't need to join after all.
*
* Parts of this data structure are specific to various scan and join
* mechanisms. It didn't seem worth creating new node types for them.
@@ -465,24 +472,31 @@ typedef struct PlannerInfo
* We store baserestrictcost in the RelOptInfo (for base relations) because
* we know we will need it at least once (to price the sequential scan)
* and may need it multiple times to price index scans.
*----------
*/
typedef enum RelOptKind
{
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(reloptkind) \
+ ((reloptkind) == RELOPT_OTHER_MEMBER_REL || \
+ (reloptkind) == RELOPT_OTHER_JOINREL)
+
+typedef struct PartitionOptInfo PartitionOptInfo;
+
typedef struct RelOptInfo
{
NodeTag type;
RelOptKind reloptkind;
/* all relations included in this RelOptInfo */
Relids relids; /* set of base relids (rangetable indexes) */
/* size estimates generated by planner */
@@ -536,20 +550,26 @@ typedef struct RelOptInfo
struct FdwRoutine *fdwroutine;
void *fdw_private;
/* used by various scans and joins: */
List *baserestrictinfo; /* RestrictInfo structures (if base
* rel) */
QualCost baserestrictcost; /* cost of evaluating the above */
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations, joins or base relations. NULL otherwise. */
+ /*
+ * TODO: Notice recursive usage of RelOptInfo.
+ */
+ PartitionOptInfo *part_info;
} RelOptInfo;
/*
* IndexOptInfo
* Per-index information for planning/optimization
*
* indexkeys[], indexcollations[], opfamily[], and opcintype[]
* each have ncolumns entries.
*
* sortopfamily[], reverse_sort[], and nulls_first[] likewise have
@@ -650,20 +670,46 @@ typedef struct ForeignKeyOptInfo
/* Derived info about whether FK's equality conditions match the query: */
int nmatched_ec; /* # of FK cols matched by ECs */
int nmatched_rcols; /* # of FK cols matched by non-EC rinfos */
int nmatched_ri; /* total # of non-EC rinfos matched to FK */
/* Pointer to eclass matching each column's condition, if there is one */
struct EquivalenceClass *eclass[INDEX_MAX_KEYS];
/* List of non-EC RestrictInfos matching each column's condition */
List *rinfos[INDEX_MAX_KEYS];
} ForeignKeyOptInfo;
+/*
+ * PartitionOptInfo
+ * Partitioning information for planning/optimization
+ *
+ * TODO: complete the comment
+ */
+typedef struct PartitionOptInfo
+{
+ NodeTag type;
+
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ RelOptInfo **part_rels; /* RelOptInfos of partitions */
+ PartitionListBound **lists; /* list bounds */
+ PartitionRangeBound **rangelowers; /* range lower bounds */
+ PartitionRangeBound **rangeuppers; /* range upper bounds */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ List **partexprs; /* partition key expressions. */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ FmgrInfo *partsupfunc; /* lookup info for support funcs */
+ KeyTypeCollInfo *tcinfo; /* type and collation info (all columns) */
+} PartitionOptInfo;
/*
* EquivalenceClasses
*
* Whenever we can determine that a mergejoinable equality clause A = B is
* not delayed by any outer join, we create an EquivalenceClass containing
* the expressions A and B to record this knowledge. If we later find another
* equivalence B = C, we add C to the existing EquivalenceClass; this may
* require merging two existing EquivalenceClasses. At the end of the qual
* distribution process, we have sets of values that are known all transitively
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..1069726 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -59,20 +59,21 @@ extern bool enable_seqscan;
extern bool enable_indexscan;
extern bool enable_indexonlyscan;
extern bool enable_bitmapscan;
extern bool enable_tidscan;
extern bool enable_sort;
extern bool enable_hashagg;
extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
double index_pages, PlannerInfo *root);
extern void cost_seqscan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_samplescan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_index(IndexPath *path, PlannerInfo *root,
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..a41f8b6
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,1365 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+-- TODO: We need to add tests for SEMI-ANTI joins.
+-- TODO: tests with placeholder vars
+--
+-- partitioned by a single column
+--
+CREATE TABLE pt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE pt1_p1 PARTITION OF pt1 FOR VALUES START (0) END (250);
+CREATE TABLE pt1_p2 PARTITION OF pt1 FOR VALUES START (250) END (500);
+CREATE TABLE pt1_p3 PARTITION OF pt1 FOR VALUES START (500) END (600);
+INSERT INTO pt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1 AS SELECT * FROM pt1;
+CREATE TABLE pt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE pt2_p1 PARTITION OF pt2 FOR VALUES START (0) END (250);
+CREATE TABLE pt2_p2 PARTITION OF pt2 FOR VALUES START (250) END (500);
+CREATE TABLE pt2_p3 PARTITION OF pt2 FOR VALUES START (500) END (600);
+INSERT INTO pt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2 AS SELECT * FROM pt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1, pt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1, pt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1 t1, upt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1 t1 RIGHT JOIN upt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE pt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE pt1_e_p1 PARTITION OF pt1_e FOR VALUES START (0) END (250);
+CREATE TABLE pt1_e_p2 PARTITION OF pt1_e FOR VALUES START (250) END (500);
+CREATE TABLE pt1_e_p3 PARTITION OF pt1_e FOR VALUES START (500) END (600);
+INSERT INTO pt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1_e AS SELECT * FROM pt1_e;
+CREATE TABLE pt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE pt2_e_p1 PARTITION OF pt2_e FOR VALUES START (0) END (250);
+CREATE TABLE pt2_e_p2 PARTITION OF pt2_e FOR VALUES START (250) END (500);
+CREATE TABLE pt2_e_p3 PARTITION OF pt2_e FOR VALUES START (500) END (600);
+INSERT INTO pt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2_e AS SELECT * FROM pt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1, pt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1, pt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_e t1, upt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 LEFT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 LEFT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_e t1 LEFT JOIN upt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 RIGHT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 RIGHT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_e t1 RIGHT JOIN upt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_e WHERE pt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_e WHERE pt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM pt1 t1, pt2 t2, pt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM pt1 t1, pt2 t2, pt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM upt1 t1, upt2 t2, upt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b) LEFT JOIN upt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b) LEFT JOIN upt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b) RIGHT JOIN upt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 RIGHT JOIN upt2 t2 ON t1.a = t2.b) RIGHT JOIN upt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM upt1 WHERE upt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2 WHERE upt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM upt1_e WHERE upt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE pt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE pt1_m_p1 PARTITION OF pt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE pt1_m_p2 PARTITION OF pt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE pt1_m_p3 PARTITION OF pt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO pt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1_m AS SELECT * FROM pt1_m;
+CREATE TABLE pt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE pt2_m_p1 PARTITION OF pt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE pt2_m_p2 PARTITION OF pt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE pt2_m_p3 PARTITION OF pt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO pt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2_m AS SELECT * FROM pt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1, pt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1, pt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_m t1, upt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_m t1 LEFT JOIN upt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 RIGHT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 RIGHT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_m t1 RIGHT JOIN upt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_m WHERE pt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_m WHERE pt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_m WHERE pt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_m WHERE pt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE pt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE pt1_l_p1 PARTITION OF pt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE pt1_l_p1_p1 PARTITION OF pt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE pt1_l_p1_p2 PARTITION OF pt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE pt1_l_p2 PARTITION OF pt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE pt1_l_p2_p1 PARTITION OF pt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE pt1_l_p2_p2 PARTITION OF pt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE pt1_l_p3 PARTITION OF pt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE pt1_l_p3_p1 PARTITION OF pt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE pt1_l_p3_p2 PARTITION OF pt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO pt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1_l AS SELECT * FROM pt1_l;
+CREATE TABLE pt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE pt2_l_p1 PARTITION OF pt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE pt2_l_p1_p1 PARTITION OF pt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE pt2_l_p1_p2 PARTITION OF pt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE pt2_l_p2 PARTITION OF pt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE pt2_l_p2_p1 PARTITION OF pt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE pt2_l_p2_p2 PARTITION OF pt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE pt2_l_p3 PARTITION OF pt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE pt2_l_p3_p1 PARTITION OF pt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE pt2_l_p3_p2 PARTITION OF pt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO pt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2_l AS SELECT * FROM pt2_l;
+--
+-- TODO: a varchar = varchar comparison is converted into a comparison
+-- varchar::text = varchar::text. Thus the partition key on c does not match
+-- the equi-join condition on c. This is fine, but can be improved. Also, as
+-- long as we have this behaviour, we get to test partial partition-wise join
+-- between multi-level partitioned relations.
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1, pt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 14) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 15) is considered for partition-wise join.
+NOTICE: join between relations (b 6) and (b 16) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1, pt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 14) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 15) is considered for partition-wise join.
+NOTICE: join between relations (b 6) and (b 16) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_l t1, upt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- TODO for outer joins the equality conditions do not appear in joininfo of
+-- children, which means that the equi-join clauses are not present for
+-- subpartitions. Hence the joins between subpartitions are not currently being
+-- considered for partition-wise join.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 LEFT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 LEFT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_l t1 LEFT JOIN upt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 RIGHT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 RIGHT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_l t1 RIGHT JOIN upt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_l WHERE pt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_l WHERE pt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_l WHERE pt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_l WHERE pt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is NOT considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.a = t2.b AND t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c AND t1.a = t3.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ERROR: the relation was considered for partition-wise join, which is not supported right now.
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is NOT considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is NOT considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+--
+-- negative testcases
+--
+CREATE TABLE pt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE pt1_n_p1 PARTITION OF pt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE pt1_n_p2 PARTITION OF pt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO pt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+CREATE TABLE pt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE pt2_n_p1 PARTITION OF pt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE pt2_n_p2 PARTITION OF pt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO pt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+CREATE TABLE pt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE pt3_n_p1 PARTITION OF pt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE pt3_n_p2 PARTITION OF pt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE pt3_n_p3 PARTITION OF pt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO pt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+CREATE TABLE pt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pt4_n_p1 PARTITION OF pt4_n FOR VALUES START (0) END (300);
+CREATE TABLE pt4_n_p2 PARTITION OF pt4_n FOR VALUES START (300) END (500);
+CREATE TABLE pt4_n_p3 PARTITION OF pt4_n FOR VALUES START (500) END (600);
+INSERT INTO pt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1, pt4_n t2 WHERE t1.a = t2.a;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Merge Join
+ Merge Cond: (t1.a = t2.a)
+ -> Sort
+ Sort Key: t1.a
+ -> Append
+ -> Seq Scan on pt1 t1
+ -> Seq Scan on pt1_p1 t1_1
+ -> Seq Scan on pt1_p2 t1_2
+ -> Seq Scan on pt1_p3 t1_3
+ -> Sort
+ Sort Key: t2.a
+ -> Append
+ -> Seq Scan on pt4_n t2
+ -> Seq Scan on pt4_n_p1 t2_1
+ -> Seq Scan on pt4_n_p2 t2_2
+ -> Seq Scan on pt4_n_p3 t2_3
+(16 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 FULL JOIN pt4_n t2 ON t1.a = t2.a;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Merge Full Join
+ Merge Cond: (t1.a = t2.a)
+ -> Sort
+ Sort Key: t1.a
+ -> Append
+ -> Seq Scan on pt1 t1
+ -> Seq Scan on pt1_p1 t1_1
+ -> Seq Scan on pt1_p2 t1_2
+ -> Seq Scan on pt1_p3 t1_3
+ -> Sort
+ Sort Key: t2.a
+ -> Append
+ -> Seq Scan on pt4_n t2
+ -> Seq Scan on pt4_n_p1 t2_1
+ -> Seq Scan on pt4_n_p2 t2_2
+ -> Seq Scan on pt4_n_p3 t2_3
+(16 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 LEFT JOIN pt2 t2 ON (t1.a < t2.b);
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------
+ Nested Loop Left Join
+ Join Filter: (t1.a < t2.b)
+ -> Append
+ -> Seq Scan on pt1 t1
+ -> Seq Scan on pt1_p1 t1_1
+ -> Seq Scan on pt1_p2 t1_2
+ -> Seq Scan on pt1_p3 t1_3
+ -> Materialize
+ -> Append
+ -> Seq Scan on pt2 t2
+ -> Seq Scan on pt2_p1 t2_1
+ -> Seq Scan on pt2_p2 t2_2
+ -> Seq Scan on pt2_p3 t2_3
+(13 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1, pt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on pt2_m t2
+ -> Seq Scan on pt2_m_p1 t2_1
+ -> Seq Scan on pt2_m_p2 t2_2
+ -> Seq Scan on pt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on pt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on pt2_m t2
+ -> Seq Scan on pt2_m_p1 t2_1
+ -> Seq Scan on pt2_m_p2 t2_2
+ -> Seq Scan on pt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on pt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on pt2_m t2
+ -> Seq Scan on pt2_m_p1 t2_1
+ -> Seq Scan on pt2_m_p2 t2_2
+ -> Seq Scan on pt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on pt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on pt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- TODO: an equalify condition on the partition keys in WHERE clause should not
+-- qualify for partition-wise join. But such a condition converts an OUTER
+-- join into an INNER join, in which case the conditions in WHERE clause can be
+-- treated as join conditions, thus qualifying the join for partition-wise
+-- join.
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1, pt2_n t2 WHERE t1.c = t2.c;
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Merge Join
+ Merge Cond: ((t1.c)::text = t2.c)
+ -> Sort
+ Sort Key: t1.c
+ -> Append
+ -> Seq Scan on pt1_n t1
+ -> Seq Scan on pt1_n_p1 t1_1
+ -> Seq Scan on pt1_n_p2 t1_2
+ -> Sort
+ Sort Key: t2.c
+ -> Append
+ -> Seq Scan on pt2_n t2
+ -> Seq Scan on pt2_n_p1 t2_1
+ -> Seq Scan on pt2_n_p2 t2_2
+(14 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1 LEFT JOIN pt2_n t2 ON (t1.c = t2.c);
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Merge Left Join
+ Merge Cond: ((t1.c)::text = t2.c)
+ -> Sort
+ Sort Key: t1.c
+ -> Append
+ -> Seq Scan on pt1_n t1
+ -> Seq Scan on pt1_n_p1 t1_1
+ -> Seq Scan on pt1_n_p2 t1_2
+ -> Sort
+ Sort Key: t2.c
+ -> Append
+ -> Seq Scan on pt2_n t2
+ -> Seq Scan on pt2_n_p1 t2_1
+ -> Seq Scan on pt2_n_p2 t2_2
+(14 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1 RIGHT JOIN pt1 t2 ON (t1.c = t2.c);
+NOTICE: join between relations (b 2) and (b 1) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Merge Right Join
+ Merge Cond: ((t1.c)::text = (t2.c)::text)
+ -> Sort
+ Sort Key: t1.c
+ -> Append
+ -> Seq Scan on pt1_n t1
+ -> Seq Scan on pt1_n_p1 t1_1
+ -> Seq Scan on pt1_n_p2 t1_2
+ -> Sort
+ Sort Key: t2.c
+ -> Append
+ -> Seq Scan on pt1 t2
+ -> Seq Scan on pt1_p1 t2_1
+ -> Seq Scan on pt1_p2 t2_2
+ -> Seq Scan on pt1_p3 t2_3
+(15 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1 FULL JOIN pt1 t2 ON (t1.c = t2.c);
+NOTICE: join between relations (b 1) and (b 2) is NOT considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------
+ Merge Full Join
+ Merge Cond: ((t1.c)::text = (t2.c)::text)
+ -> Sort
+ Sort Key: t1.c
+ -> Append
+ -> Seq Scan on pt1_n t1
+ -> Seq Scan on pt1_n_p1 t1_1
+ -> Seq Scan on pt1_n_p2 t1_2
+ -> Sort
+ Sort Key: t2.c
+ -> Append
+ -> Seq Scan on pt1 t2
+ -> Seq Scan on pt1_p1 t2_1
+ -> Seq Scan on pt1_p2 t2_2
+ -> Seq Scan on pt1_p3 t2_3
+(15 rows)
+
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..128987b
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,408 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+-- TODO: We need to add tests for SEMI-ANTI joins.
+-- TODO: tests with placeholder vars
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE pt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE pt1_p1 PARTITION OF pt1 FOR VALUES START (0) END (250);
+CREATE TABLE pt1_p2 PARTITION OF pt1 FOR VALUES START (250) END (500);
+CREATE TABLE pt1_p3 PARTITION OF pt1 FOR VALUES START (500) END (600);
+INSERT INTO pt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1 AS SELECT * FROM pt1;
+
+CREATE TABLE pt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE pt2_p1 PARTITION OF pt2 FOR VALUES START (0) END (250);
+CREATE TABLE pt2_p2 PARTITION OF pt2 FOR VALUES START (250) END (500);
+CREATE TABLE pt2_p3 PARTITION OF pt2 FOR VALUES START (500) END (600);
+INSERT INTO pt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2 AS SELECT * FROM pt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1, pt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1, pt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1 t1, upt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1 t1 RIGHT JOIN upt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE pt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE pt1_e_p1 PARTITION OF pt1_e FOR VALUES START (0) END (250);
+CREATE TABLE pt1_e_p2 PARTITION OF pt1_e FOR VALUES START (250) END (500);
+CREATE TABLE pt1_e_p3 PARTITION OF pt1_e FOR VALUES START (500) END (600);
+INSERT INTO pt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1_e AS SELECT * FROM pt1_e;
+
+CREATE TABLE pt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE pt2_e_p1 PARTITION OF pt2_e FOR VALUES START (0) END (250);
+CREATE TABLE pt2_e_p2 PARTITION OF pt2_e FOR VALUES START (250) END (500);
+CREATE TABLE pt2_e_p3 PARTITION OF pt2_e FOR VALUES START (500) END (600);
+INSERT INTO pt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2_e AS SELECT * FROM pt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1, pt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1, pt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_e t1, upt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 LEFT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 LEFT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_e t1 LEFT JOIN upt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 RIGHT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_e t1 RIGHT JOIN pt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_e t1 RIGHT JOIN upt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_e WHERE pt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_e WHERE pt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM pt1 t1, pt2 t2, pt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM pt1 t1, pt2 t2, pt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM upt1 t1, upt2 t2, upt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b) LEFT JOIN upt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) LEFT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b) LEFT JOIN upt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 LEFT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 LEFT JOIN upt2 t2 ON t1.a = t2.b) RIGHT JOIN upt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (pt1 t1 RIGHT JOIN pt2 t2 ON t1.a = t2.b) RIGHT JOIN pt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (upt1 t1 RIGHT JOIN upt2 t2 ON t1.a = t2.b) RIGHT JOIN upt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM pt1 WHERE pt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2 WHERE pt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM pt1_e WHERE pt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM upt1 WHERE upt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2 WHERE upt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM upt1_e WHERE upt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE pt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE pt1_m_p1 PARTITION OF pt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE pt1_m_p2 PARTITION OF pt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE pt1_m_p3 PARTITION OF pt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO pt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1_m AS SELECT * FROM pt1_m;
+
+CREATE TABLE pt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE pt2_m_p1 PARTITION OF pt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE pt2_m_p2 PARTITION OF pt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE pt2_m_p3 PARTITION OF pt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO pt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2_m AS SELECT * FROM pt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1, pt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1, pt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_m t1, upt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_m t1 LEFT JOIN upt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 RIGHT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 RIGHT JOIN pt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_m t1 RIGHT JOIN upt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_m WHERE pt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_m WHERE pt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_m WHERE pt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_m WHERE pt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE pt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE pt1_l_p1 PARTITION OF pt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE pt1_l_p1_p1 PARTITION OF pt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE pt1_l_p1_p2 PARTITION OF pt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE pt1_l_p2 PARTITION OF pt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE pt1_l_p2_p1 PARTITION OF pt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE pt1_l_p2_p2 PARTITION OF pt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE pt1_l_p3 PARTITION OF pt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE pt1_l_p3_p1 PARTITION OF pt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE pt1_l_p3_p2 PARTITION OF pt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO pt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt1_l AS SELECT * FROM pt1_l;
+
+CREATE TABLE pt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE pt2_l_p1 PARTITION OF pt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE pt2_l_p1_p1 PARTITION OF pt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE pt2_l_p1_p2 PARTITION OF pt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE pt2_l_p2 PARTITION OF pt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE pt2_l_p2_p1 PARTITION OF pt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE pt2_l_p2_p2 PARTITION OF pt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE pt2_l_p3 PARTITION OF pt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE pt2_l_p3_p1 PARTITION OF pt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE pt2_l_p3_p2 PARTITION OF pt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO pt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE upt2_l AS SELECT * FROM pt2_l;
+
+--
+-- TODO: a varchar = varchar comparison is converted into a comparison
+-- varchar::text = varchar::text. Thus the partition key on c does not match
+-- the equi-join condition on c. This is fine, but can be improved. Also, as
+-- long as we have this behaviour, we get to test partial partition-wise join
+-- between multi-level partitioned relations.
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1, pt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1, pt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_l t1, upt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- TODO for outer joins the equality conditions do not appear in joininfo of
+-- children, which means that the equi-join clauses are not present for
+-- subpartitions. Hence the joins between subpartitions are not currently being
+-- considered for partition-wise join.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 LEFT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 LEFT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_l t1 LEFT JOIN upt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 RIGHT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_l t1 RIGHT JOIN pt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM upt1_l t1 RIGHT JOIN upt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_l WHERE pt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_l WHERE pt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM pt1_l WHERE pt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM pt2_l WHERE pt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM upt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM upt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.a = t2.b AND t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c AND t1.a = t3.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+--
+-- negative testcases
+--
+
+CREATE TABLE pt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE pt1_n_p1 PARTITION OF pt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE pt1_n_p2 PARTITION OF pt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO pt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+
+CREATE TABLE pt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE pt2_n_p1 PARTITION OF pt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE pt2_n_p2 PARTITION OF pt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO pt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+
+CREATE TABLE pt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE pt3_n_p1 PARTITION OF pt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE pt3_n_p2 PARTITION OF pt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE pt3_n_p3 PARTITION OF pt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO pt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+
+CREATE TABLE pt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pt4_n_p1 PARTITION OF pt4_n FOR VALUES START (0) END (300);
+CREATE TABLE pt4_n_p2 PARTITION OF pt4_n FOR VALUES START (300) END (500);
+CREATE TABLE pt4_n_p3 PARTITION OF pt4_n FOR VALUES START (500) END (600);
+INSERT INTO pt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1, pt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 FULL JOIN pt4_n t2 ON t1.a = t2.a;
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1 t1 LEFT JOIN pt2 t2 ON (t1.a < t2.b);
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1, pt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_m t1 LEFT JOIN pt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+-- TODO: an equalify condition on the partition keys in WHERE clause should not
+-- qualify for partition-wise join. But such a condition converts an OUTER
+-- join into an INNER join, in which case the conditions in WHERE clause can be
+-- treated as join conditions, thus qualifying the join for partition-wise
+-- join.
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1, pt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1 LEFT JOIN pt2_n t2 ON (t1.c = t2.c);
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1 RIGHT JOIN pt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM pt1_n t1 FULL JOIN pt1 t2 ON (t1.c = t2.c);
Sorry forgot to mention: this patch applies on top of the v7 patches posted
by Amit Langote on 27th June (
/messages/by-id/81371428-bb4b-1e33-5ad6-8c5c51b52cb7@lab.ntt.co.jp
).
On Tue, Jul 19, 2016 at 7:41 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
On Fri, Jul 8, 2016 at 12:11 AM, Robert Haas <robertmhaas@gmail.com>
wrote:I haven't reviewed this code yet due to being busy with 9.6, but I
think this is a very important query planner improvement with the
potential for big wins on queries involving large amounts of data.Suppose we have a pair of equi-partitioned tables. Right now, if we
choose to perform a hash join, we'll have to build a giant hash table
with all of the rows from every inner partition and then probe it for
every row in every outer partition. If there are few enough inner
rows that the resultant hash table still fits in work_mem, this is
somewhat inefficient but not terrible - but if it causes us to have to
batch the hash join where we otherwise would not need to do so, then
it really sucks. Similarly, if we decide to merge-join each pair of
partitions, a partitionwise join may be able to use an internal sort
on some or all partitions whereas if we had to deal with all of the
data at the same time we'd need an external sort, possibly multi-pass.Or we might be able to use indexes directly without need of a MergeAppend.
And if we choose a nested loop, say over an inner index-scan, we do
O(outer rows) index probes with this optimization but O(outer rows *
inner partitions) index probes without it.In addition, parallel query can benefit significantly from this kind
of optimization. Tom recently raised the case of an appendrel where
every child has a parallel-safe path but not every child has a partial
path; currently, we can't go parallel in that case, but it's easy to
see that we could handle it by scheduling the appendrel's children
across a pool of workers. If we had this optimization, that sort of
thing would be much more likely to be useful, because it could create
appendrels where each member is an N-way join between equipartitioned
tables. That's particularly important right now because of the
restriction that a partial path must be driven by a Parallel SeqScan,
but even after that restriction is lifted it's easy to imagine that
the effective degree of parallelism for a single index scan may be
limited - so this kind of thing may significantly increase the number
of workers that a given query can use productively.+1.
The attached patch implements the logic to assess whether two partitioned
tables can be joined using partition-wise join technique described in my
last
mail on this thread.Two partitioned relations are considered for partition-wise join if
following
conditions are met (See build_joinrel_part_info() for details):
1. Both the partitions have same number of partitions, with same number of
partition keys and partitioned by same strategy - range or list.
2. They have matching datatypes for partition keys (partkey_types_match())
3. For list partitioned relations, they have same lists for each pair of
partitions, paired by position in which they appear.
4. For range partitioned relations, they have same bounds for each pair of
partitions, paired by their position when ordered in ascending fashion on
the
upper bounds.
5. There exists an equi-join condition for each pair of partition keys,
paired
by the position in which they appear.Partition-wise join technique can be applied under more lenient
constraints [1]
e.g. joins between tables with different number of partitions but having
same
bounds/lists for the common partitions. I am planning to defer that to a
later
version of this feature.A join executed using partition-wise join technique is itself a relation
partitioned by the similar partitioning scheme as the joining relations
with
the partition keys combined from the joining relations.A PartitionOptInfo (uses name similar to RelOptInfo or IndexOptInfo)
structure
is used to store the partitioning information for a given base or relation.
In build_simple_rel(), we construct PartitionOptInfo structure for the
given
base relation by copying the relation's PartitionDesc and PartitionKey
(structures from Amit Langote's patch). While doing so, all the partition
keys
are stored as expressions. The structure also holds the RelOptInfos of the
partition relations. For a join relation, most of the PartitionOptInfo is
copied from either of the joining relations, except the partition keys and
RelOptInfo of partition relations. Partition keys of the join relations are
created by combing partition keys from both the joining relations. The
logic to
cosnstruct RelOptInfo for the partition-wise join relations is yet to be
implemented.Since the logic to create the paths and RelOptInfos for partition-wise join
relations is not implemented yet, a query which can use partition-wise join
fails with error
"ERROR: the relation was considered for partition-wise join, which is not
supported right now.". It will also print messages to show which of the
joins
can and can not use partition-wise join technique e.g.
"NOTICE: join between relations (b 1) and (b 2) is considered for
partition-wise join." The relations are indicated by their relid in the
query.
OR
"NOTICE: join between relations (b 1) and (b 2) is NOT considered for
partition-wise join.".
These messages are for debugging only, and will be removed once path
creation
logic is implemented.The patch adds a test partition_join.sql, which has a number of positive
and
negative testcases for joins between partitioned tables.--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Hi All,
PFA the patch to support partition-wise joins for partitioned tables. The
patch
is based on the declarative parition support patches provided by Amit
Langote
on 26th August 2016. The previous patch added support to assess whether two
tables can be joined using partition-wise join technique, but did not have
complete support to create plans which used partition-wise technique. This
patch implements three important pieces for supporting partition-wise join
1. Logic to assess whether join between two partitioned tables can be
executed
using partition-wise join technique.
2. Construct RelOptInfo's representating join between matching partitions of
the joining relations and add join paths to those RelOptInfo's
3. Add append paths to the RelOptInfo representing the join between
partitioned
tables. Rest of the planner code chooses the optimal path for join.
make_join_rel() now calls try_partition_wise_join(), which executes all of
the
steps listed above. If the joining partitioned relations are deemed fit for
partition-wise join, we create one RelOptInfo (if not already present)
representing a join between every pair of partitions to be joined. Since the
join between parents is deemed legal, the join between the partitions is
also
legal, hence legality of the join is not checked again. RelOptInfo
representing
the join between partitions is constructed by translating the relevant
members
of RelOptInfo of the parent join relation. Similarly SpecialJoinInfo,
restrictlist (for given join order) are constructed by translating those for
the parent join.
make_join_rel() is split into two portions, a. that deals with constructing
restrictlist and RelOptInfo for join relation b. that creates paths for the
join. The second portion is separated into a function
populate_joinrel_with_paths(), which is reused in try_partition_wise_join()
to
create paths for join between matching partitions.
set_append_rel_pathlist() generates paths for child relations, marks the
empty
children as dummy relations and creates append paths by collecting paths
with
similar properties (parameterization and pathkeys) from non-empty children.
It
then adds append paths to the parent relation. This patch divides
set_append_rel_pathlist() into two parts a. marking empty child relations as
dummy and generating paths for non-empty children. b. collecting children
paths
into append paths for parent. Part b is separate into a function
add_paths_to_append_rel() which is reused for collecting paths from
partition-wise join child relations to construct append paths for join
between
partitioned tables.
For an N-way join between partitioned tables, make_join_rel() is called as
many
times as the number of valid join orders exist. For each such call, we will
add
paths to join between partitions for corresponding join order between those
partitions. We can generate the append paths for parent joinrel only after
all
such join orders have been considered. Hence before setting cheapest path
forx
parent join relation, we set the cheapest path for each join relation
between
partitions, followed by creating append paths for the parent joinrel. This
method needs some readjustment for multi-level partitions (TODO item 2
below).
A GUC enable_partition_wise_join is added to enable or disable
partition-wise
join technique. I think the GUC is useful similar to other join related GUCs
like enable_hashjoin.
parameterized paths: While creating parameterized paths for child relations
of
a partitioned tables, we do not have an idea as to whether we will be able
to
use partition-wise join technique or not. Also we do not know the child
partition of the other partitioned table, to which a given partition would
join. Hence we do not create paths parameterized by child partitions of
other
partitioned relations. But path for child of a partitioned relation
parameterized by other parent relation, can be considered to be
parameterised
by any child relation of the other partitioned relation by replacing the
parent
parameters by corresponding child parameters. This condition is used to
eliminate parameterized paths while creating merge and hash joins, to decide
the resultant parameterization of a join between child partitions and to
create
nested loop paths with inner path parameterized by outer relation where
inner
and outer relations are child partitions. While creating such nest loop join
paths we translate the path parameterized by other parent partitioned
relation,
to that parameterized by the required child.
Functions like select_outer_pathkeys_for_merge(), make_sort_from_pathkeys(),
find_ec_member_for_tle() which did not expect to be called for a child
relation, are now used for child partition relations for joins. These
functions
are adjusted for that usage.
Testing:
I have added partition_join.sql testcase to test partition-wise join
feature.
That file has extensive tests for list, range, multi-level partitioning
schemes
and various kinds of joins including nested loop join with inner relation
parameterized by outer relationThat file has extensive tests for list,
range,
multi-level partitioning schemes and various kinds of joins including nested
loop join with inner relation parameterized by outer relation.
make check passes clean.
TODOs:
1. Instead of storing partitioning information in RelOptInfo of each of the
partitioned relations (base and join relations), we can keep a list of
canonical partition schemes in PlannerInfo. Every RelOptInfo gets a pointer
to
the member of list representing the partitioning scheme of corresponding
relation. RelOptInfo's of all similarly partitioned relations get the same
pointer thus making it easy to match the partitioning schemes by comparing
the
pointers. While we are supporting only exact partition matching scheme now,
it's possible to extend this method to match compatible partitioning
schemes by
maintaining a list of compatible partitioning schemes.
Right now, I have moved some partition related structures from partition.c
to
partition.h. These structures are still being reviewed and might change when
Amit Langote improves his patches. Having canonical partitioning scheme in
PlannerInfo may not require moving those structures out. So, that code is
still
under development. A related change is renaming RangeBound structure in Amit
Langote's patches to PartitionRangeBound to avoid name conflict with
rangetypes.h. That change too should vanish once we decide where to keep
that
structure and its final name.
2. Multi-level partitioned tables: For some reason path created for joining
partitions are not being picked up as the cheapest paths. I think, we need
to
finalize the lower level paths before moving upwards in the partition
hierarchy. But I am yet to investigate the issue here.
RelOptInfo::parent_relid
should point to top parents rather than immediate parents.
3. Testing: need more tests for testing partition-wise join with foreign
tables
as partitions. More tests for parameterized joins for multi-level
partitioned
joins.
4. Remove bms_to_char(): I have added this function to print Relids in the
debugger. I have found it very useful to quickly examine Relids in debugger,
which otherwise wasn't so easy. If others find it useful too, I can create a
separate patch to be considered for a separate commit.
5. In add_paths_to_append_rel() to find the possible set of outer relations
for
generating parameterized paths for a given join. This code needs to be
adjusted
to eliminate the parent relations possible set of outer relations for a join
between child partitions.
6. Add support to reparameterize more types of paths for child relations. I
will add this once we finalize the method to reparameterize a parent path
for
child partition.
7. The patch adds make_joinrel() (name needs to be changed because of its
similariy with make_join_rel()) to construct an empty RelOptInfo for a join
between partitions. The function copies code doing the same from
build_join_rel(). build_join_rel() too can use this function, if we decide
to
retain it.
8. Few small TODOs related to code reorganization, proper function,
variable naming etc. are in the patch. pg_indent run.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join.patchtext/x-patch; charset=US-ASCII; name=pg_dp_join.patchDownload
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index f17ac29..8ce704a 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -43,80 +43,20 @@
#include "utils/builtins.h"
#include "utils/datum.h"
#include "utils/memutils.h"
#include "utils/fmgroids.h"
#include "utils/inval.h"
#include "utils/lsyscache.h"
#include "utils/ruleutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
-/* Type and collation information for partition key columns */
-typedef struct KeyTypeCollInfo
-{
- Oid *typid;
- int32 *typmod;
- int16 *typlen;
- bool *typbyval;
- char *typalign;
- Oid *typcoll;
-} KeyTypeCollInfo;
-
-/*
- * Partition key information
- */
-typedef struct PartitionKeyData
-{
- char strategy; /* partition strategy */
- int16 partnatts; /* number of partition attributes */
- AttrNumber *partattrs; /* partition attnums */
- Oid *partopfamily; /* OIDs of operator families */
- Oid *partopcintype; /* OIDs of opclass declared input data types */
- FmgrInfo *partsupfunc; /* lookup info for support funcs */
- List *partexprs; /* partition key expressions, if any */
- char **partcolnames; /* partition key column names */
- KeyTypeCollInfo *tcinfo; /* type and collation info (all columns) */
-} PartitionKeyData;
-
-/* Internal representation of a list partition bound */
-typedef struct PartitionListInfo
-{
- int nvalues; /* number of values in the following array */
- Datum *values; /* values contained in the list */
- bool *nulls;
-} PartitionListInfo;
-
-/* Internal representation of a range partition bound */
-typedef struct RangeBound
-{
- Datum *val; /* composite bound value, if any */
- bool infinite; /* bound is +/- infinity */
- bool inclusive; /* bound is inclusive (vs exclusive) */
- bool lower; /* this is the lower (vs upper) bound */
-} RangeBound;
-
-typedef struct PartitionRangeInfo
-{
- RangeBound *lower;
- RangeBound *upper;
-} PartitionRangeInfo;
-
-/*
- * Information about a single partition
- */
-typedef struct PartitionInfoData
-{
- Oid oid; /* partition OID */
- PartitionListInfo *list; /* list partition info */
- PartitionRangeInfo *range; /* range partition info */
-} PartitionInfoData;
-
/*
* PartitionKeyExecInfo
*
* This struct holds the information needed to extract partition
* column values from a heap tuple.
*
* Key copy of the rd_partkey of rel
* ExpressionState exec state for expressions, or NIL if none
*/
typedef struct PartitionKeyExecInfo
@@ -226,37 +166,37 @@ static PartitionListInfo *make_list_from_spec(PartitionKey key,
static PartitionListInfo *copy_list_info(PartitionListInfo *src,
PartitionKey key);
static bool equal_list_info(PartitionKey key, PartitionListInfo *l1,
PartitionListInfo *l2);
static bool partition_list_values_equal(PartitionKey key,
Datum val1, Datum val2);
/* Range partition related support functions */
static PartitionRangeInfo *make_range_from_spec(PartitionKey key,
PartitionRangeSpec *range_spec);
-static RangeBound *make_range_bound(PartitionKey key, List *val, bool inclusive,
+static PartitionRangeBound *make_range_bound(PartitionKey key, List *val, bool inclusive,
bool lower);
static PartitionRangeInfo *copy_range_info(PartitionRangeInfo *src,
PartitionKey key);
-static RangeBound *copy_range_bound(RangeBound *src, PartitionKey key);
+static PartitionRangeBound *copy_range_bound(PartitionRangeBound *src, PartitionKey key);
static bool equal_range_info(PartitionKey key, PartitionRangeInfo *r1,
PartitionRangeInfo *r2);
static int32 partition_range_cmp(PartitionKey key, PartitionRangeInfo *r1,
PartitionRangeInfo *r2);
-static int32 partition_range_bound_cmp(PartitionKey key, RangeBound *b1,
- RangeBound *b2);
+static int32 partition_range_bound_cmp(PartitionKey key, PartitionRangeBound *b1,
+ PartitionRangeBound *b2);
static int32 partition_range_tuple_cmp(PartitionKey key,
Datum *val1, Datum *val2);
static bool partition_range_overlaps(PartitionKey key,
PartitionRangeInfo *r1, PartitionRangeInfo *r2);
-static bool tuple_rightof_bound(PartitionKey key, Datum *tuple, RangeBound *bound);
-static bool tuple_leftof_bound(PartitionKey key, Datum *tuple, RangeBound *bound);
+static bool tuple_rightof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound);
+static bool tuple_leftof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound);
static int range_partition_bsearch(PartitionKey key, PartitionDesc pdesc,
Datum *tuple);
/*
* Partition key related functions
*/
/*
* RelationBuildPartitionKey
* Build and attach to relcache partition key data of relation
@@ -1097,21 +1037,21 @@ list_overlaps_existing_partition(PartitionKey key,
}
/*
* Is a new partition's range empty?
*/
static bool
partition_range_empty(PartitionKey key, PartitionRangeSpec *range_spec)
{
PartitionRangeInfo *range;
- RangeBound *lower,
+ PartitionRangeBound *lower,
*upper;
range = make_range_from_spec(key, range_spec);
lower = range->lower;
upper = range->upper;
/*
* Range is not empty if one (and only one) of the bounds is infinity.
* Both cannot be infinite because of how the syntax is specified.
*/
@@ -2104,27 +2044,27 @@ make_range_from_spec(PartitionKey key, PartitionRangeSpec *range_spec)
range_spec->lowerinc,
true);
range->upper = make_range_bound(key,
range_spec->upper,
range_spec->upperinc,
false);
return range;
}
-static RangeBound *
+static PartitionRangeBound *
make_range_bound(PartitionKey key, List *val, bool inclusive, bool lower)
{
- RangeBound *bound;
+ PartitionRangeBound *bound;
ListCell *cell;
- bound = (RangeBound *) palloc0(sizeof(RangeBound));
+ bound = (PartitionRangeBound *) palloc0(sizeof(PartitionRangeBound));
bound->infinite = (val == NIL);
bound->inclusive = inclusive;
bound->lower = lower;
if (val)
{
int i;
bound->val = (Datum *) palloc0(key->partnatts * sizeof(Datum));
@@ -2157,28 +2097,28 @@ copy_range_info(PartitionRangeInfo *src, PartitionKey key)
{
PartitionRangeInfo *result;
result = (PartitionRangeInfo *) palloc0(sizeof(PartitionRangeInfo));
result->lower = copy_range_bound(src->lower, key);
result->upper = copy_range_bound(src->upper, key);
return result;
}
-static RangeBound *
-copy_range_bound(RangeBound *src, PartitionKey key)
+static PartitionRangeBound *
+copy_range_bound(PartitionRangeBound *src, PartitionKey key)
{
int i;
int partnatts = get_partition_key_natts(key);
- RangeBound *result;
+ PartitionRangeBound *result;
- result = (RangeBound *) palloc0(sizeof(RangeBound));
+ result = (PartitionRangeBound *) palloc0(sizeof(PartitionRangeBound));
result->infinite = src->infinite;
result->inclusive = src->inclusive;
result->lower = src->lower;
if (src->val)
{
result->val = (Datum *) palloc0(partnatts * sizeof(Datum));
for (i = 0; i < partnatts; i++)
result->val[i] = datumCopy(src->val[i],
key->tcinfo->typbyval[i],
@@ -2212,21 +2152,21 @@ partition_range_cmp(PartitionKey key, PartitionRangeInfo *r1,
cmp = partition_range_bound_cmp(key, r1->lower, r2->lower);
if (cmp == 0)
cmp = partition_range_bound_cmp(key, r1->upper, r2->upper);
return cmp;
}
/* Returns for two range partition bounds whether, b1 <=, =, >= b2 */
static int32
-partition_range_bound_cmp(PartitionKey key, RangeBound *b1, RangeBound *b2)
+partition_range_bound_cmp(PartitionKey key, PartitionRangeBound *b1, PartitionRangeBound *b2)
{
int32 result;
/*
* First, handle cases involving infinity, which don't require invoking
* the comparison proc.
*/
if (b1->infinite && b2->infinite)
{
/*
@@ -2337,31 +2277,31 @@ range_partition_bsearch(PartitionKey key, PartitionDesc pdesc,
}
low = idx + 1;
}
return -1;
}
/* Does range key lie to the right of partition bound */
static bool
-tuple_rightof_bound(PartitionKey key, Datum *tuple, RangeBound *bound)
+tuple_rightof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound)
{
int32 cmpval = partition_range_tuple_cmp(key, tuple, bound->val);
if (!cmpval)
return bound->lower ? bound->inclusive : !bound->inclusive;
return cmpval > 0;
}
/* Does range key lie to the left of partition bound */
static bool
-tuple_leftof_bound(PartitionKey key, Datum *tuple, RangeBound *bound)
+tuple_leftof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound)
{
int32 cmpval = partition_range_tuple_cmp(key, tuple, bound->val);
if (!cmpval)
return !bound->lower ? bound->inclusive : !bound->inclusive;
return cmpval < 0;
}
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3b8fa6b..cd14840 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -204,20 +204,31 @@ _outBitmapset(StringInfo str, const Bitmapset *bms)
}
/* for use by extensions which define extensible nodes */
void
outBitmapset(StringInfo str, const Bitmapset *bms)
{
_outBitmapset(str, bms);
}
/*
+ * TODO: remove, used for debugging through gdb.
+ */
+char *
+bms_to_char(const Bitmapset *bms)
+{
+ StringInfo str = makeStringInfo();
+ outBitmapset(str, bms);
+ return str->data;
+}
+
+/*
* Print the value of a Datum given its type.
*/
void
outDatum(StringInfo str, Datum value, int typlen, bool typbyval)
{
Size length,
i;
char *s;
length = datumGetSize(value, typbyval, typlen);
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 04264b4..09781be 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -119,20 +119,24 @@ static void check_output_expressions(Query *subquery,
static void compare_tlist_datatypes(List *tlist, List *colTypes,
pushdown_safety_info *safetyInfo);
static bool targetIsInAllPartitionLists(TargetEntry *tle, Query *query);
static bool qual_is_pushdown_safe(Query *subquery, Index rti, Node *qual,
pushdown_safety_info *safetyInfo);
static void subquery_push_qual(Query *subquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels);
+static void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
/*
* make_one_rel
* Finds all possible access paths for executing a query, returning a
* single rel that represents the join of all base rels in the query.
*/
RelOptInfo *
make_one_rel(PlannerInfo *root, List *joinlist)
{
@@ -908,20 +912,40 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childRTE = root->simple_rte_array[childRTindex];
/*
* The child rel's RelOptInfo was already created during
* add_base_rels_to_query.
*/
childrel = find_base_rel(root, childRTindex);
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
/*
+ * Copy/Modify targetlist. Partition-wise join technique may consider
+ * an OUTER join of another child relation with this child relation.
+ * In that case, even if this child is deemed empty, we will require
+ * the targetlist of this child to construct the nullable side. Hence
+ * set the targetlist before we prove that the child is empty and stop
+ * processing further.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ appinfo);
+
+ /*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
* baserestrictinfo quals are needed before we can check for
* constraint exclusion; so do that first and then check to see if we
* can disregard this child.
*
* As of 8.4, the child rel's targetlist might contain non-Var
* expressions, which means that substitution into the quals could
* produce opportunities for const-simplification, and perhaps even
* pseudoconstant quals. To deal with this, we strip the RestrictInfo
@@ -953,38 +977,25 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
if (relation_excluded_by_constraints(root, childrel, childRTE))
{
/*
* This child need not be scanned, so we can omit it from the
* appendrel.
*/
set_dummy_rel_pathlist(childrel);
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying join quals. */
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
appinfo);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo);
/*
* We have to make child entries in the EquivalenceClass data
* structures as well. This is needed either if the parent
* participates in some eclass joins (because we will want to consider
* inner-indexscan joins on the individual children) or if the parent
* has useful pathkeys (because we should try to build MergeAppend
* paths that produce those sort orderings).
*/
if (rel->has_eclass_joins || has_useful_pathkeys(root, rel))
@@ -1115,41 +1126,32 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
/*
* set_append_rel_pathlist
* Build access paths for an "append relation"
*/
static void
set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte)
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
- * Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * Generate access paths for each member relation and remember the
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
/* Re-locate the child RTE and RelOptInfo */
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
childrel = root->simple_rel_array[childRTindex];
@@ -1170,20 +1172,46 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
/*
* If child is dummy, ignore it.
*/
if (IS_DUMMY_REL(childrel))
continue;
/*
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid = true;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
* the unparameterized Append path we are constructing for the parent.
* If not, there's no workable unparameterized path.
*/
if (childrel->cheapest_total_path->param_info == NULL)
subpaths = accumulate_append_subpath(subpaths,
childrel->cheapest_total_path);
else
@@ -2188,20 +2216,22 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
* join_search_one_level. After that, we're done creating paths for
* the joinrel, so run set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
rel = (RelOptInfo *) lfirst(lc);
+ generate_partition_wise_join_paths(root, rel);
+
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
#ifdef OPTIMIZER_DEBUG
debug_print_rel(root, rel);
#endif
}
@@ -2849,20 +2879,77 @@ remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel)
* OK, we don't need it. Replace the expression with a NULL constant.
* Preserve the exposed type of the expression, in case something
* looks at the rowtype of the subquery's result.
*/
tle->expr = (Expr *) makeNullConst(exprType(texpr),
exprTypmod(texpr),
exprCollation(texpr));
}
}
+/*
+ * generate_partition_wise_join_paths
+ * Create appends paths containing partition-wise join paths for given
+ * join relation.
+ */
+static void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *live_children = NIL;
+ int cnt_part;
+ PartitionOptInfo *part_info = rel->part_info;
+
+ /* Handle only join relations. */
+ if (rel->reloptkind != RELOPT_JOINREL &&
+ rel->reloptkind != RELOPT_OTHER_JOINREL)
+ return;
+
+ /* If the relation is not partitioned, nothing to do. */
+ if (!part_info)
+ return;
+
+ for (cnt_part = 0; cnt_part < part_info->nparts; cnt_part++)
+ {
+ RelOptInfo *child_rel = part_info->part_rels[cnt_part];
+
+ /* Ignore dummy child. */
+ if (!IS_DUMMY_REL(child_rel))
+ {
+ /* Collect the paths from child joinrel. */
+ /* TODO: we need to reassess how do we do this, since the join
+ * between parents will require append paths for the child joinrel.
+ */
+ generate_partition_wise_join_paths(root, child_rel);
+
+ /* Find the cheapest of the paths for this rel. */
+ set_cheapest(child_rel);
+
+ /* Should we generate any gather paths? */
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ live_children = lappend(live_children, child_rel);
+ }
+ }
+
+ /*
+ * Create append paths by collecting sub paths from live children. Even if
+ * there are no live children, we should create an append path with no
+ * subpaths i.e. a dummy access path.
+ */
+ add_paths_to_append_rel(root, rel, live_children);
+
+ if (live_children)
+ pfree(live_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
*****************************************************************************/
#ifdef OPTIMIZER_DEBUG
static void
print_relids(PlannerInfo *root, Relids relids)
{
int x;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 2a49639..a23da1c 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -119,20 +119,21 @@ bool enable_seqscan = true;
bool enable_indexscan = true;
bool enable_indexonlyscan = true;
bool enable_bitmapscan = true;
bool enable_tidscan = true;
bool enable_sort = true;
bool enable_hashagg = true;
bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
typedef struct
{
PlannerInfo *root;
QualCost total;
} cost_qual_eval_context;
static List *extract_nonindex_conditions(List *qual_clauses, List *indexquals);
static MergeScanSelCache *cached_scansel(PlannerInfo *root,
RestrictInfo *rinfo,
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index 0e50ad5..62a3f3a 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2359,20 +2359,22 @@ eclass_useful_for_merging(PlannerInfo *root,
/*
* Note we don't test ec_broken; if we did, we'd need a separate code path
* to look through ec_sources. Checking the members anyway is OK as a
* possibly-overoptimistic heuristic.
*/
/* If specified rel is a child, we must consider the topmost parent rel */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->parent_relids;
else
relids = rel->relids;
/* If rel already includes all members of eclass, no point in searching */
if (bms_is_subset(eclass->ec_relids, relids))
return false;
/* To join, we need a member not in the given rel */
foreach(lc, eclass->ec_members)
{
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index cc7384f..8b34ab9 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -18,23 +18,29 @@
#include "executor/executor.h"
#include "foreign/fdwapi.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void match_unsorted_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void consider_parallel_nestloop(PlannerInfo *root,
RelOptInfo *joinrel,
RelOptInfo *outerrel,
RelOptInfo *innerrel,
@@ -121,20 +127,22 @@ add_paths_to_joinrel(PlannerInfo *root,
* Decide whether it's sensible to generate parameterized paths for this
* joinrel, and if so, which relations such paths should require. There
* is usually no need to create a parameterized result path unless there
* is a join order restriction that prevents joining one of our input rels
* directly to the parameter source rel instead of joining to the other
* input rel. (But see allow_star_schema_join().) This restriction
* reduces the number of parameterized paths we have to deal with at
* higher join levels, without compromising the quality of the resulting
* plan. We express the restriction as a Relids set that must overlap the
* parameterization of any proposed join path.
+ * TODO: do we need sjinfo created for children to added to the list in the
+ * planner info? OR how do we handle the code below?
*/
foreach(lc, root->join_info_list)
{
SpecialJoinInfo *sjinfo = (SpecialJoinInfo *) lfirst(lc);
/*
* SJ is relevant to this join if we have some part of its RHS
* (possibly not all of it), and haven't yet joined to its LHS. (This
* test is pretty simplistic, but should be sufficient considering the
* join has already been proven legal.) If the SJ is relevant, it
@@ -272,20 +280,35 @@ try_nestloop_path(PlannerInfo *root,
Path *outer_path,
Path *inner_path,
List *pathkeys,
JoinType jointype,
JoinPathExtraData *extra)
{
Relids required_outer;
JoinCostWorkspace workspace;
/*
+ * An inner path parameterized by the parent relation of outer
+ * relation needs to be reparameterized by the outer relation to be used
+ * for parameterized nested loop join.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_for_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
* doesn't like the look of it, which could only happen if the nestloop is
* still parameterized.
*/
required_outer = calc_nestloop_required_outer(outer_path,
inner_path);
if (required_outer &&
((!bms_overlap(required_outer, extra->param_source_rels) &&
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..6378d2e 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -7,38 +7,71 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* src/backend/optimizer/path/joinrels.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
static void make_rels_by_clause_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static void make_rels_by_clauseless_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static SpecialJoinInfo * build_partition_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1,
+ List *append_rel_infos2);
+static PartitionOptInfo *build_joinrel_part_info(RelOptInfo *rel1,
+ RelOptInfo *rel2, JoinType jointype,
+ List *restrictlist);
+static bool have_same_part_info(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
+static bool partkey_types_match(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2);
+static bool have_same_partition_lists(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2);
+static bool have_same_partition_bounds(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2);
+static bool compare_partition_bounds(PartitionOptInfo *part_info,
+ PartitionRangeBound *bound1, PartitionRangeBound *bound2);
+static bool match_joinrel_part_info(RelOptInfo *joinrel, RelOptInfo *rel1,
+ RelOptInfo *rel2, JoinType jointype,
+ List *restrictlist);
/*
* join_search_one_level
* Consider ways to produce join relations containing exactly 'level'
* jointree items. (This is one step of the dynamic-programming method
* embodied in standard_join_search.) Join rel nodes for each feasible
* combination of lower-level rels are created and returned in a list.
* Implementation paths are created for each such joinrel, too.
*
@@ -717,20 +750,44 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
/*
* If we've already proven this join is empty, we needn't consider any
* more paths for it.
*/
if (is_dummy_rel(joinrel))
{
bms_free(joinrelids);
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Create paths to join given input relation and add those to the given
+ * joinrel. The SpecialJoinInfo provides details about the join and the
+ * restrictlist contains the join clauses and the other clauses applicable
+ * for given pair of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
* is provably empty too; in which case throw away any previously computed
* paths and mark the join as dummy. (We do it this way since it's
* conceivable that dummy-ness of a multi-element join might only be
* noticeable for certain construction paths.)
*
* Also, a provably constant-false join restriction typically means that
* we can skip evaluating one or both sides of the join. We do this by
@@ -861,27 +918,22 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
mark_dummy_rel(rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
break;
default:
/* other values not expected here */
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
-
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
* a join-order restriction arising from special or lateral joins.
*
* In practice this is always used with have_relevant_joinclause(), and so
* could be merged with that function, but it seems clearer to separate the
* two concerns. We need this test because there are degenerate cases where
* a clauseless join must be performed to satisfy join-order restrictions.
* Also, if one rel has a lateral reference to the other, or both are needed
@@ -1242,10 +1294,744 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
/* constant NULL is as good as constant FALSE for our purposes */
if (con->constisnull)
return true;
if (!DatumGetBool(con->constvalue))
return true;
}
}
return false;
}
+
+/*
+ * If the join between the given two relations can be executed as
+ * partition-wise join create the join relations for partition-wise join,
+ * create paths for those and then create append paths to combine
+ * partition-wise join results.
+ *
+ * TODO: naming convention in this function is screwd up, sometimes we use
+ * part_ to indicate a partition variable and sometimes we use parent_ to
+ * indicate parent variable. Need to organize it better.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ PartitionOptInfo *part_info1 = rel1->part_info;
+ PartitionOptInfo *part_info2 = rel2->part_info;
+ int nparts;
+ int cnt_parts;
+ StringInfo rel1_desc;
+ StringInfo rel2_desc;
+ PartitionOptInfo *part_info;
+
+ if (!joinrel->part_info)
+ {
+ /* Can this join be executed using partition-wise join? */
+ joinrel->part_info = build_joinrel_part_info(rel1, rel2,
+ parent_sjinfo->jointype,
+ parent_restrictlist);
+
+ /* If partition-wise join is not possible, nothing to do. */
+ if (!joinrel->part_info)
+ return;
+ }
+ else
+ {
+ /*
+ * Generally, we should check whether the partition scheme for the join
+ * is same as the partitioning scheme of both the joining relations. If
+ * not, we should create a new PartitionOptInfo for new partitioning
+ * scheme. But we allow partition-wise join only in those cases, when
+ * the partitioning scheme of resultant relation is same irrespective
+ * of the order in which the relations are joined. Hence make sure that
+ * the already computed partition scheme for join matches that required
+ * by the current pair of joining relations.
+ */
+ Assert(match_joinrel_part_info(joinrel, rel1, rel2,
+ parent_sjinfo->jointype,
+ parent_restrictlist));
+ }
+
+ part_info = joinrel->part_info;
+ nparts = part_info->nparts;
+ rel1_desc = makeStringInfo();
+ rel2_desc = makeStringInfo();
+
+ /* TODO: remove this notice when finalising the patch. */
+ outBitmapset(rel1_desc, rel1->relids);
+ outBitmapset(rel2_desc, rel2->relids);
+ elog(NOTICE, "join between relations %s and %s is considered for partition-wise join.",
+ rel1_desc->data, rel2_desc->data);
+
+ /*
+ * Create join relations for the partition relations, if they do not exist
+ * already. Add paths to those for the given pair of joining relations.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *part_joinrel;
+ RelOptInfo *part_rel1 = part_info1->part_rels[cnt_parts];
+ RelOptInfo *part_rel2 = part_info2->part_rels[cnt_parts];
+ SpecialJoinInfo *sjinfo;
+ List *restrictlist;
+ List *join_aris;
+ List *ari1;
+ List *ari2;
+ Relids joinrelids;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(part_rel1->relids, part_rel2->relids));
+
+ /* Construct Relids set that identifies the joinrel. */
+ joinrelids = bms_union(part_rel1->relids, part_rel2->relids);
+
+ /*
+ * Gather the AppendRelInfos for base partition relations
+ * partiticipating in the given partition relations. We need them
+ * construct partition-wise join relation, special join info and
+ * restriction list by substituting the Var and relids from parent to
+ * child.
+ */
+ ari1 = find_appendrelinfos_by_relids(root, part_rel1->relids);
+ ari2 = find_appendrelinfos_by_relids(root, part_rel2->relids);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ sjinfo = build_partition_join_sjinfo(root, parent_sjinfo, ari1, ari2);
+
+ /* Construct the parent-child relid map for the join relation. */
+ join_aris = list_concat(ari1, ari2);
+
+ /*
+ * Construct restrictions applicable to the partition-wise join from
+ * those applicable to the join between the parents.
+ */
+ restrictlist = (List *) adjust_partitionrel_attrs(root,
+ (Node *)parent_restrictlist,
+ join_aris);
+
+ part_joinrel = part_info->part_rels[cnt_parts];
+
+ /* Construct the join relation for given partition of the join. */
+ if (!part_joinrel)
+ {
+ part_joinrel = make_joinrel(root, RELOPT_OTHER_JOINREL,
+ joinrelids);
+
+ /*
+ * Fill partition join relation by translating information from the
+ * parent join relation.
+ */
+ fill_partition_join_rel(root, part_rel1, part_rel2, part_joinrel,
+ joinrel, sjinfo, restrictlist, join_aris);
+
+ part_info->part_rels[cnt_parts] = part_joinrel;
+
+ add_joinrel_to_list(root, part_joinrel);
+ }
+
+ /* TODO: set_append_rel_size() calls add_child_rel_equivalences() for
+ * adding child equivalence classes one parent at a time. So, we do not
+ * add equivalence classes with multiple child relations. Do we need to
+ * do that? Possibily because of the parent node translation above we
+ * don't need it. Anyway, is there a way to verify it?
+ */
+ Assert(bms_equal(part_joinrel->relids, joinrelids));
+
+ bms_free(joinrelids);
+
+ /*
+ * If we've already proven that this join is empty, we needn't consider
+ * any more paths for it.
+ */
+ if (is_dummy_rel(part_joinrel))
+ continue;
+
+ populate_joinrel_with_paths(root, part_rel1, part_rel2, part_joinrel,
+ sjinfo, restrictlist);
+
+ /*
+ * If the partition themselves are partitioned, try partition-wise join
+ * recursively.
+ * TODO: we need to decide the correct place for this function to be
+ * called. The recursive nature of this call probably requires
+ * AppendPath to be added before we try to populate the other kinds of
+ * join paths for parent relations. So, we may have to call this
+ * function before populate_joinrel_with_paths().
+ */
+ try_partition_wise_join(root, part_rel1, part_rel2, part_joinrel, sjinfo,
+ restrictlist);
+ }
+}
+
+/*
+ * Construct the SpecialJoinInfo for the partition-wise join using parents'
+ * special join info. Also, instead of
+ * constructing an sjinfo everytime, we should probably save it in
+ * root->join_info_list and search within it like join_is_legal?
+ */
+static SpecialJoinInfo *
+build_partition_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1, List *append_rel_infos2)
+{
+ SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo);
+ sjinfo->min_lefthand = adjust_partition_relids(sjinfo->min_lefthand,
+ append_rel_infos1);
+ sjinfo->min_righthand = adjust_partition_relids(sjinfo->min_righthand,
+ append_rel_infos2);
+ sjinfo->syn_lefthand = adjust_partition_relids(sjinfo->syn_lefthand,
+ append_rel_infos1);
+ sjinfo->syn_righthand = adjust_partition_relids(sjinfo->syn_righthand,
+ append_rel_infos2);
+
+ /* Replace the Var nodes of parent with those of children in expressions. */
+ sjinfo->semi_rhs_exprs = (List *) adjust_partitionrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ append_rel_infos2);
+ return sjinfo;
+}
+
+/*
+ * have_same_partition_lists
+ *
+ * For given list partitioned relations, return true if lists for all the
+ * partitions of both the relations match. Return false otherwise.
+ */
+static bool
+have_same_partition_lists(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2)
+{
+ int cnt_parts;
+
+ Assert(part_info1->strategy == PARTITION_STRAT_LIST &&
+ part_info2->strategy == PARTITION_STRAT_LIST);
+
+ Assert(part_info1->nparts == part_info2->nparts);
+
+ /* List partition has only one partition key. */
+ Assert(part_info1->partnatts == 1 && part_info2->partnatts == 1);
+
+ for (cnt_parts = 0; cnt_parts < part_info1->nparts; cnt_parts++)
+ {
+ PartitionListInfo *list1 = part_info1->lists[cnt_parts];
+ PartitionListInfo *list2 = part_info2->lists[cnt_parts];
+ int cnt;
+
+ /*
+ * If number of items in the lists do not match or the one of the lists
+ * contains NULL value and other doesn't, lists do not match.
+ *
+ * TODO: This condition can be relaxed to accomodate subset of items,
+ * but probably not in the first cut.
+ */
+ if (list1->nvalues != list2->nvalues)
+ return false;
+
+ /* Compare actual values in the list. */
+ for (cnt = 0; cnt < list1->nvalues; cnt++)
+ {
+ Datum cmpval;
+
+ if (list1->nulls[cnt] != list2->nulls[cnt])
+ return false;
+
+ /* Skip NULL value comparisons. */
+ if (list1->nulls[cnt])
+ continue;
+
+ cmpval = FunctionCall2Coll(&part_info1->partsupfunc[0],
+ part_info1->tcinfo->typcoll[0],
+ list1->values[cnt],
+ list2->values[cnt]);
+ if (DatumGetInt32(cmpval))
+ return false;
+ }
+ }
+
+ /* Ok, everything matches, return true. */
+ return true;
+}
+
+/*
+ * have_same_partition_bounds
+ *
+ * For given partitioned relations, return true if the bounds of all the
+ * partitions of the both the relations match. Return false otherwise.
+ */
+static bool
+have_same_partition_bounds(PartitionOptInfo *part_info1,
+ PartitionOptInfo *part_info2)
+{
+ int cnt_parts;
+ Assert(part_info1->strategy == PARTITION_STRAT_RANGE &&
+ part_info2->strategy == PARTITION_STRAT_RANGE);
+
+ Assert(part_info1->nparts == part_info2->nparts);
+
+ for (cnt_parts = 0; cnt_parts < part_info1->nparts; cnt_parts++)
+ {
+ PartitionRangeBound *lower1 = part_info1->ranges[cnt_parts]->lower;
+ PartitionRangeBound *lower2 = part_info2->ranges[cnt_parts]->lower;
+ PartitionRangeBound *upper1 = part_info1->ranges[cnt_parts]->upper;
+ PartitionRangeBound *upper2 = part_info2->ranges[cnt_parts]->upper;
+
+ if (!compare_partition_bounds(part_info1, lower1, lower2) ||
+ !compare_partition_bounds(part_info1, upper1, upper2))
+ return false;
+ }
+
+ /* Ok, everything matches. */
+ return true;
+}
+
+/*
+ * compare_partition_bounds
+ *
+ * Return true if given bound specifications match.
+ */
+static bool
+compare_partition_bounds(PartitionOptInfo *part_info,
+ PartitionRangeBound *bound1,
+ PartitionRangeBound *bound2)
+{
+ int cnt_pks;
+ Datum *val1 = bound1->val;
+ Datum *val2 = bound2->val;
+
+ if (bound1->infinite != bound2->infinite ||
+ bound1->inclusive != bound2->inclusive ||
+ bound1->lower != bound2->lower)
+ return false;
+
+ /*
+ * TODO:
+ * Following part is common with compare_range_keys(), but that takes
+ * PartitionKey as argument, which we don't have here.
+ */
+ for (cnt_pks = 0; cnt_pks < part_info->partnatts; cnt_pks++)
+ {
+ Datum cmpval;
+
+ cmpval = FunctionCall2Coll(&part_info->partsupfunc[cnt_pks],
+ part_info->tcinfo->typcoll[cnt_pks],
+ val1[cnt_pks], val2[cnt_pks]);
+
+ if (DatumGetInt32(cmpval))
+ return false;
+ }
+
+ /* Ok, everything matches. */
+ return true;
+}
+
+/*
+ * partkey_types_match
+ *
+ * Returns true if the partition key datatype and collation match for given
+ * partitioned relations. Returns false otherwise.
+ */
+static bool
+partkey_types_match(PartitionOptInfo *part_info1, PartitionOptInfo *part_info2)
+{
+ int cnt_pks;
+ Oid *partopfamily1 = part_info1->partopfamily;
+ Oid *partopfamily2 = part_info2->partopfamily;
+ Oid *partopcintype1 = part_info1->partopcintype;
+ Oid *partopcintype2 = part_info2->partopcintype;
+ FmgrInfo *partsupfunc1 = part_info1->partsupfunc;
+ FmgrInfo *partsupfunc2 = part_info2->partsupfunc;
+ KeyTypeCollInfo *tcinfo1 = part_info1->tcinfo;
+ KeyTypeCollInfo *tcinfo2 = part_info2->tcinfo;
+
+ if (part_info1->partnatts != part_info1->partnatts)
+ return false;
+
+ for (cnt_pks = 0; cnt_pks < part_info1->partnatts; cnt_pks++)
+ {
+ /*
+ * It suffices to check the OID of support function as it always has
+ * two arguemnts and returns boolean. For types, it suffices to match
+ * the type id, mod and collation; len, byval and align are depedent on
+ * the first two.
+ */
+ if (partopfamily1[cnt_pks] != partopfamily2[cnt_pks] ||
+ partopcintype1[cnt_pks] != partopcintype2[cnt_pks] ||
+ partsupfunc1[cnt_pks].fn_oid != partsupfunc2[cnt_pks].fn_oid ||
+ tcinfo1->typid[cnt_pks] != tcinfo2->typid[cnt_pks] ||
+ tcinfo1->typmod[cnt_pks] != tcinfo2->typmod[cnt_pks] ||
+ tcinfo1->typcoll[cnt_pks] != tcinfo2->typcoll[cnt_pks])
+ return false;
+ }
+
+ /* Everything matches. */
+ return true;
+}
+
+/*
+ * Substitute oldrelids with newrelids in the given Relids set. It recycles the
+ * given relids input.
+ */
+Relids
+adjust_partition_relids(Relids relids, List *append_rel_infos)
+{
+ ListCell *lc;
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *ari = lfirst(lc);
+
+ /* Remove old, add new */
+ if (bms_is_member(ari->parent_relid, relids))
+ {
+ relids = bms_del_member(relids, ari->parent_relid);
+ relids = bms_add_member(relids, ari->child_relid);
+ }
+ }
+ return relids;
+}
+
+/*
+ * Check whether the given two partitioning schemes are same.
+ */
+static bool
+have_same_part_info(PartitionOptInfo *part_info1, PartitionOptInfo *part_info2)
+{
+ int cnt;
+
+ /*
+ * If number of partitions, number of partition keys and partitioning
+ * strategy of the joining relations do not match, we can not apply
+ * partition-wise join.
+ *
+ * TODO: it should be possible to push an inner join down even if the number of
+ * partitions differ but the common partitions match. In such a case pushing
+ * down outer joins would be tricky, but still doable using empty relation
+ * for non-existing partition.
+ */
+ if (!part_info1 || !part_info2 ||
+ part_info1->nparts != part_info2->nparts ||
+ part_info1->strategy != part_info2->strategy ||
+ part_info1->partnatts != part_info2->partnatts)
+ return false;
+
+ /*
+ * Partition-wise join between multi-level partitioned tables is not
+ * supported, since the partition hierarchy doesn't get translated into the
+ * corresponding RelOptInfo hierarchy. Since the partition hierarchy is
+ * flattened, if we add append paths to intermediate partition relations,
+ * the corresponding rows will be added multiple times.
+ */
+ for (cnt = 0; cnt < part_info1->nparts; cnt++)
+ {
+ RelOptInfo *part_rel1 = part_info1->part_rels[cnt];
+ RelOptInfo *part_rel2 = part_info2->part_rels[cnt];
+ if (!part_rel1 || !part_rel2 || part_rel1->part_info ||
+ part_rel2->part_info)
+ return false;
+ }
+
+ /*
+ * Partition-wise join can not be applied if datatypes and collations of
+ * the partition keys do not match.
+ */
+ if (!partkey_types_match(part_info1, part_info2))
+ return false;
+
+ /*
+ * Partition-wise join can not be applied if the partition bounds or lists
+ * of joining relations do not match.
+ */
+ switch (part_info1->strategy)
+ {
+ case PARTITION_STRAT_LIST:
+ if (!have_same_partition_lists(part_info1, part_info2))
+ return false;
+ break;
+
+ case PARTITION_STRAT_RANGE:
+ if (!have_same_partition_bounds(part_info1, part_info2))
+ return false;
+ break;
+
+ default:
+ /* Unknown partition strategy. */
+ return false;
+ }
+
+ return true;
+}
+
+/*
+ * build_joinrel_part_info
+ *
+ * Given partition description of two joining relations, construct partition
+ * description for join between those relations. If we can execute
+ * partition-wise join the resultant join is partitioned in the same way as the
+ * joining relations. Otherwise, it is not partitioned and in such case the
+ * function returns NULL.
+ *
+ * TODO find the right place for this function.
+ *
+ * TODO:
+ * This function and
+ * build_partition_info() should be named consistently e.g.
+ * build_joinrel_partition_info and build_simplerel_partition_info or
+ * build_baserel_partition_info resp.
+ *
+ * TODO: this code can be simplified a lot if we precompute the partitioning
+ * compatibility between relations. See Robert's idea in 9th August mail on
+ * thread "Is any ordering of N-way join always partition-wise joinable?"
+ */
+static PartitionOptInfo *
+build_joinrel_part_info(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionOptInfo *part_info;
+ PartitionOptInfo *part_info1 = rel1->part_info;
+ PartitionOptInfo *part_info2 = rel2->part_info;
+ int cnt;
+ int num_pks;
+
+ /* Do nothing, if user doesn't want to try partition-wise join. */
+ if (!enable_partition_wise_join)
+ return NULL;
+
+ if (!have_same_part_info(part_info1, part_info2))
+ return NULL;
+
+ /*
+ * Partition-wise join can not be applied if there is no equi-join
+ * condition between partition keys.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, jointype, restrictlist))
+ return NULL;
+
+ /* The join is partitioned the similar to the joining relations. */
+ part_info = makeNode(PartitionOptInfo);
+
+ /* Information related to the partititions. */
+ part_info->nparts = part_info1->nparts;
+ /* Allocate space for partition RelOptInfos, which will be filled later. */
+ part_info->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) *
+ part_info->nparts);
+ part_info->lists = part_info1->lists;
+ part_info->ranges = part_info1->ranges;
+
+ /* Information related to partition keys. */
+ part_info->strategy = part_info1->strategy;
+ part_info->partnatts = part_info1->partnatts;
+ part_info->partopfamily = part_info1->partopfamily;
+ part_info->partopcintype = part_info1->partopcintype;
+ part_info->partsupfunc = part_info1->partsupfunc;
+ part_info->tcinfo = part_info1->tcinfo;
+ num_pks = part_info->partnatts;
+ part_info->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(part_info1->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(part_info2->partexprs[cnt]));
+ part_info->partexprs[cnt] = pkexpr;
+ }
+
+ return part_info;
+}
+
+/*
+ * Returns true if the given relations have equi-join clauses on all the
+ * corresponding partition keys.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionOptInfo *part_info1 = rel1->part_info;
+ PartitionOptInfo *part_info2 = rel2->part_info;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ Assert(part_info1->partnatts == part_info2->partnatts);
+ num_pks = part_info1->partnatts;
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip non-equi-join clauses. */
+ if (!rinfo->can_join ||
+ rinfo->hashjoinoperator == InvalidOid ||
+ !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+ /*
+ * If clause of form rel1_expr op rel2_expr OR rel2_expr op rel1_expr,
+ * match the operands to the relations. Otherwise, the clause is
+ * not an equi-join between partition keys of joining relations.
+ */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ if (ipk1 == ipk2)
+ pk_has_clause[ipk1] = true;
+ }
+
+ /*
+ * If every pair of partition key from either of the joining relation has
+ * at least one equi-join clause associated with it, we have an equi-join
+ * between all corresponding partition keys.
+ */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * match_expr_to_partition_keys
+ *
+ * Find the partition key which is same as the given expression. If found,
+ * return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ PartitionOptInfo *part_info = rel->part_info;
+ int cnt_pks;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() will have simplied if more
+ * than one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < part_info->partnatts; cnt_pks++)
+ {
+ List *pkexprs = part_info->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
+
+/*
+ * Checks
+ * 1. if the partitioning scheme of the join relation match that of the joining
+ * relations.
+ * 2. if there exists equi-join condition between the partition keys of the
+ * joining relations.
+ * 3. if the partition keys of the join contain the partition keys of both the
+ * relations.
+ */
+static bool
+match_joinrel_part_info(RelOptInfo *joinrel, RelOptInfo *rel1,
+ RelOptInfo *rel2, JoinType jointype,
+ List *restrictlist)
+{
+ int cnt;
+ int num_pks;
+ PartitionOptInfo *join_part_info = joinrel->part_info;
+ PartitionOptInfo *part_info1 = rel1->part_info;
+ PartitionOptInfo *part_info2= rel1->part_info;
+
+ Assert(enable_partition_wise_join);
+
+ /*
+ * If partitioning scheme of the join doesn't match that of the joining
+ * relations, join relations is not partitioned in the same way as one or
+ * both of the joining relations.
+ */
+ if (!have_same_part_info(join_part_info, part_info1) ||
+ !have_same_part_info(join_part_info, part_info2))
+ return false;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, the given partition scheme can not be used for
+ * partition-wise join between these two relations.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, jointype, restrictlist))
+ return false;
+
+ /*
+ * If the partition keys from either of the joining relations are not part
+ * of the partition keys of the join relation, again we can not use the
+ * given partition scheme for joining the given relations partition-wise.
+ */
+ Assert(join_part_info->partnatts == part_info1->partnatts);
+ Assert(join_part_info->partnatts == part_info2->partnatts);
+
+ num_pks = join_part_info->partnatts;
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = join_part_info->partexprs[cnt];
+ List *pkexpr1 = part_info1->partexprs[cnt];
+ List *pkexpr2 = part_info2->partexprs[cnt];
+ List *diff_list;
+
+ diff_list = list_difference(pkexpr1, pkexpr);
+ if (diff_list)
+ {
+ list_free(diff_list);
+ return false;
+ }
+
+ diff_list = list_difference(pkexpr2, pkexpr);
+ if (diff_list)
+ {
+ list_free(diff_list);
+ return false;
+ }
+ }
+
+ return true;
+}
diff --git a/src/backend/optimizer/path/pathkeys.c b/src/backend/optimizer/path/pathkeys.c
index 4436ac1..dba6772 100644
--- a/src/backend/optimizer/path/pathkeys.c
+++ b/src/backend/optimizer/path/pathkeys.c
@@ -1081,26 +1081,38 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
RelOptInfo *joinrel)
{
List *pathkeys = NIL;
int nClauses = list_length(mergeclauses);
EquivalenceClass **ecs;
int *scores;
int necs;
ListCell *lc;
int j;
+ Relids relids;
/* Might have no mergeclauses */
if (nClauses == 0)
return NIL;
/*
+ * Code below scores equivalence classes by how many equivalence members
+ * can produce join clauses for this join relation. Equivalence members
+ * which do not cover the parents of a partition-wise join relation, can
+ * produce join clauses for partition-wise join relation.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = joinrel->parent_relids;
+ else
+ relids = joinrel->relids;
+
+ /*
* Make arrays of the ECs used by the mergeclauses (dropping any
* duplicates) and their "popularity" scores.
*/
ecs = (EquivalenceClass **) palloc(nClauses * sizeof(EquivalenceClass *));
scores = (int *) palloc(nClauses * sizeof(int));
necs = 0;
foreach(lc, mergeclauses)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
@@ -1126,21 +1138,21 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
continue;
/* compute score */
score = 0;
foreach(lc2, oeclass->ec_members)
{
EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
/* Potential future join partner? */
if (!em->em_is_const && !em->em_is_child &&
- !bms_overlap(em->em_relids, joinrel->relids))
+ !bms_overlap(em->em_relids, relids))
score++;
}
ecs[necs] = oeclass;
scores[necs] = score;
necs++;
}
/*
* Find out if we have all the ECs mentioned in query_pathkeys; if so we
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 32f4031..b221e2c 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -235,21 +235,22 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
const AttrNumber *reqColIdx,
bool adjust_tlist_in_place,
int *p_numsortkeys,
AttrNumber **p_sortColIdx,
Oid **p_sortOperators,
Oid **p_collations,
bool **p_nullsFirst);
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
static Material *make_material(Plan *lefttree);
static WindowAgg *make_windowagg(List *tlist, Index winref,
int partNumCols, AttrNumber *partColIdx, Oid *partOperators,
int ordNumCols, AttrNumber *ordColIdx, Oid *ordOperators,
int frameOptions, Node *startOffset, Node *endOffset,
Plan *lefttree);
static Group *make_group(List *tlist, List *qual, int numGroupCols,
@@ -1507,21 +1508,21 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
Plan *subplan;
/*
* We don't want any excess columns in the sorted tuples, so request a
* smaller tlist. Otherwise, since Sort doesn't project, tlist
* requirements pass through.
*/
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
return plan;
}
/*
* create_group_plan
*
* Create a Group plan for 'best_path' and (recursively) plans
@@ -3517,31 +3518,33 @@ create_mergejoin_plan(PlannerInfo *root,
List *innerpathkeys;
int nClauses;
Oid *mergefamilies;
Oid *mergecollations;
int *mergestrategies;
bool *mergenullsfirst;
int i;
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
* inputs. However, if we're intending to sort an input's result, it's
* best to request a small tlist so we aren't sorting more data than
* necessary.
*/
- outer_plan = create_plan_recurse(root, best_path->jpath.outerjoinpath,
+ outer_plan = create_plan_recurse(root, outer_path,
(best_path->outersortkeys != NIL) ? CP_SMALL_TLIST : 0);
- inner_plan = create_plan_recurse(root, best_path->jpath.innerjoinpath,
+ inner_plan = create_plan_recurse(root, inner_path,
(best_path->innersortkeys != NIL) ? CP_SMALL_TLIST : 0);
/* Sort join qual clauses into best execution order */
/* NB: do NOT reorder the mergeclauses */
joinclauses = order_qual_clauses(root, best_path->jpath.joinrestrictinfo);
/* Get the join qual clauses (in plain expression form) */
/* Any pseudoconstant clauses are ignored here */
if (IS_OUTER_JOIN(best_path->jpath.jointype))
{
@@ -3573,48 +3576,52 @@ create_mergejoin_plan(PlannerInfo *root,
otherclauses = (List *)
replace_nestloop_params(root, (Node *) otherclauses);
}
/*
* Rearrange mergeclauses, if needed, so that the outer variable is always
* on the left; mark the mergeclause restrictinfos with correct
* outer_is_left status.
*/
mergeclauses = get_switched_clauses(best_path->path_mergeclauses,
- best_path->jpath.outerjoinpath->parent->relids);
+ outer_path->parent->relids);
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
outerpathkeys = best_path->outersortkeys;
}
else
- outerpathkeys = best_path->jpath.outerjoinpath->pathkeys;
+ outerpathkeys = outer_path->pathkeys;
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
innerpathkeys = best_path->innersortkeys;
}
else
- innerpathkeys = best_path->jpath.innerjoinpath->pathkeys;
+ innerpathkeys = inner_path->pathkeys;
/*
* If specified, add a materialize node to shield the inner plan from the
* need to handle mark/restore.
*/
if (best_path->materialize_inner)
{
Plan *matplan = (Plan *) make_material(inner_plan);
/*
@@ -5330,25 +5337,25 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any
* further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
exprvars = pull_var_clause((Node *) sortexpr,
PVC_INCLUDE_AGGREGATES |
PVC_INCLUDE_WINDOWFUNCS |
PVC_INCLUDE_PLACEHOLDERS);
foreach(k, exprvars)
{
if (!tlist_member_ignore_relabel(lfirst(k), tlist))
@@ -5445,57 +5452,58 @@ find_ec_member_for_tle(EquivalenceClass *ec,
Expr *emexpr;
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
emexpr = em->em_expr;
while (emexpr && IsA(emexpr, RelabelType))
emexpr = ((RelabelType *) emexpr)->arg;
if (equal(emexpr, tlexpr))
return em;
}
return NULL;
}
/*
* make_sort_from_pathkeys
* Create sort plan to sort according to given pathkeys
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
Oid *sortOperators;
Oid *collations;
bool *nullsFirst;
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
&sortColIdx,
&sortOperators,
&collations,
&nullsFirst);
/* Now build the Sort node */
return make_sort(lefttree, numsortkeys,
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 592214b..7e3e3b8 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -1873,20 +1873,79 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
appinfo);
}
result = (Node *) newnode;
}
else
result = adjust_appendrel_attrs_mutator(node, &context);
return result;
}
+/*
+ * find_appendrelinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appendrelinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *ari_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *ari = lfirst(lc);
+
+ if (bms_is_member(ari->child_relid, relids))
+ ari_list = lappend(ari_list, ari);
+ }
+
+ Assert(list_length(ari_list) == bms_num_members(relids));
+ return ari_list;
+}
+
+/*
+ * adjust_partitionrel_attrs
+ * Replace the Var nodes in given node with the corresponding Var nodes
+ * of the child. Given list of AppendRelInfo nodes holds the mapping
+ * between parent and child Var nodes.
+ *
+ * TODO:
+ * Note: This function is expected to be called only in case of partitioned
+ * tables, where the child table has the same schema as the parent table. This
+ * allows us to just restamp the Var nodes with child's relid.
+ *
+ * While doing so, we need to make sure to translate non-expression information
+ * in nodes like RestrictInfo.
+ */
+Node *
+adjust_partitionrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos)
+{
+ ListCell *lc;
+
+ /*
+ * TODO: for partitioned tables, since the partitions have same structure
+ * as that of their parents, it should suffice to just restamp the Var node
+ * rather than copying, but both require a new tree being allocated.
+ * TODO: Instead of copying and mutating the trees one child relation at a
+ * time, we should be able to do this en-masse for all the partitions
+ * involved.
+ */
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *append_rel_info = lfirst(lc);
+ node = adjust_appendrel_attrs(root, node, append_rel_info);
+ }
+
+ return node;
+}
+
static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
AppendRelInfo *appinfo = context->appinfo;
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index abb7507..4e04133 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -16,21 +16,23 @@
#include <math.h>
#include "miscadmin.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
#include "utils/selfuncs.h"
typedef enum
{
COSTS_EQUAL, /* path costs are fuzzily equal */
COSTS_BETTER1, /* first path is cheaper than second */
@@ -1889,20 +1891,21 @@ calc_nestloop_required_outer(Path *outer_path, Path *inner_path)
/* inner_path can require rels from outer path, but not vice versa */
Assert(!bms_overlap(outer_paramrels, inner_path->parent->relids));
/* easy case if inner path is not parameterized */
if (!inner_paramrels)
return bms_copy(outer_paramrels);
/* else, form the union ... */
required_outer = bms_union(outer_paramrels, inner_paramrels);
/* ... and remove any mention of now-satisfied outer rels */
required_outer = bms_del_members(required_outer,
outer_path->parent->relids);
+
/* maintain invariant that required_outer is exactly NULL if empty */
if (bms_is_empty(required_outer))
{
bms_free(required_outer);
required_outer = NULL;
}
return required_outer;
}
/*
@@ -3202,10 +3205,160 @@ reparameterize_path(PlannerInfo *root, Path *path,
rel,
spath->subpath,
spath->path.pathkeys,
required_outer);
}
default:
break;
}
return NULL;
}
+
+/*
+ * reparameterize_path_for_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ */
+Path *
+reparameterize_path_for_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+
+ /*
+ * If the path is not parameterized by parent of the given relation, it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appendrelinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = adjust_partition_relids(bms_copy(old_ppi->ppi_req_outer),
+ child_aris);
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = (List *) adjust_partitionrel_attrs(root,
+ (Node *) old_ppi->ppi_clauses,
+ child_aris);
+
+ /* Adjust the path target. */
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_partitionrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ new_path->param_info = new_ppi;
+
+ /*
+ * Change parameterization of sub paths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_for_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_for_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = (List *) adjust_partitionrel_attrs(root,
+ (Node *) jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_for_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexquals = (List *) adjust_partitionrel_attrs(root,
+ (Node *) ipath->indexquals,
+ child_aris);
+ ipath->indexquals = (List *) adjust_partitionrel_attrs(root,
+ (Node *) ipath->indexorderbys,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index deef560..cea06c7 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -8,29 +8,34 @@
*
*
* IDENTIFICATION
* src/backend/optimizer/util/relnode.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
+#include "nodes/makefuncs.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
{
Relids join_relids; /* hash key --- MUST BE FIRST */
RelOptInfo *join_rel;
} JoinHashEntry;
static void build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel);
@@ -40,20 +45,24 @@ static List *build_joinrel_restrictlist(PlannerInfo *root,
RelOptInfo *inner_rel);
static void build_joinrel_joinlist(RelOptInfo *joinrel,
RelOptInfo *outer_rel,
RelOptInfo *inner_rel);
static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_restrictlist);
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static PartitionOptInfo *build_partition_info(PlannerInfo *root,
+ RelOptInfo *rel);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
/*
* setup_simple_rel_arrays
* Prepare the arrays we use for quickly accessing base relations.
*/
void
setup_simple_rel_arrays(PlannerInfo *root)
{
Index rti;
@@ -165,27 +174,33 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
break;
default:
elog(ERROR, "unrecognized RTE kind: %d",
(int) rte->rtekind);
break;
}
/* Save the finished struct in the query's simple_rel_array */
root->simple_rel_array[relid] = rel;
+ /* Get the partitioning information, if any. */
+ if (rte->rtekind == RTE_RELATION)
+ rel->part_info = build_partition_info(root, rel);
+ else
+ rel->part_info = NULL;
+
/*
* If this rel is an appendrel parent, recurse to build "other rel"
* RelOptInfos for its children. They are "other rels" because they are
* not in the main join tree, but we will need RelOptInfos to plan access
* to them.
*/
- if (rte->inh)
+ if (!rel->part_info && rte->inh)
{
ListCell *l;
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != relid)
continue;
@@ -307,20 +322,70 @@ find_join_rel(PlannerInfo *root, Relids relids)
if (bms_equal(rel->relids, relids))
return rel;
}
}
return NULL;
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
*
* 'joinrelids' is the Relids set that uniquely identifies the join
* 'outer_rel' and 'inner_rel' are relation nodes for the relations to be
* joined
* 'sjinfo': join context info
* 'restrictlist_ptr': result variable. If not NULL, *restrictlist_ptr
* receives the list of RestrictInfo nodes that apply to this
@@ -356,21 +421,25 @@ build_join_rel(PlannerInfo *root,
joinrel,
outer_rel,
inner_rel);
return joinrel;
}
/*
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
+
+ Assert(!IS_OTHER_REL(outer_rel->reloptkind) &&
+ !IS_OTHER_REL(inner_rel->reloptkind));
joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
joinrel->consider_startup = (root->tuple_fraction > 0);
joinrel->consider_param_startup = false;
joinrel->consider_parallel = false;
joinrel->reltarget = create_empty_pathtarget();
joinrel->pathlist = NIL;
joinrel->ppilist = NIL;
joinrel->partial_pathlist = NIL;
@@ -402,61 +471,25 @@ build_join_rel(PlannerInfo *root,
joinrel->serverid = InvalidOid;
joinrel->userid = InvalidOid;
joinrel->useridiscurrent = false;
joinrel->fdwroutine = NULL;
joinrel->fdw_private = NULL;
joinrel->baserestrictinfo = NIL;
joinrel->baserestrictcost.startup = 0;
joinrel->baserestrictcost.per_tuple = 0;
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
+ joinrel->part_info = NULL;
+ joinrel->parent_relids = NULL;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Computer information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
* this join (ie, are needed for higher joinclauses or final output).
*
* NOTE: the tlist order for a join rel will depend on which pair of outer
* and inner rels we first try to build it from. But the contents should
* be the same regardless.
*/
build_joinrel_tlist(root, joinrel, outer_rel);
@@ -510,57 +543,146 @@ build_join_rel(PlannerInfo *root,
* assume this doesn't matter, because we should hit all the same baserels
* and joinclauses while building up to this joinrel no matter which we
* take; therefore, we should make the same decision here however we get
* here.
*/
if (inner_rel->consider_parallel && outer_rel->consider_parallel &&
is_parallel_safe(root, (Node *) restrictlist) &&
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the query's PlannerInfo. */
+ add_joinrel_to_list(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
* to the appropriate sublist. Note: you might think the Assert on number
* of members should be for equality, but some of the level 1 rels might
* have been joinrels already, so we can only assert <=.
*/
if (root->join_rel_level)
{
Assert(root->join_cur_level > 0);
Assert(root->join_cur_level <= bms_num_members(joinrel->relids));
root->join_rel_level[root->join_cur_level] =
lappend(root->join_rel_level[root->join_cur_level], joinrel);
}
return joinrel;
}
+RelOptInfo *
+make_joinrel(PlannerInfo *root, RelOptKind reloptkind, Relids joinrelids)
+{
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_copy(joinrelids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_info = NULL;
+ joinrel->parent_relids = NULL;
+
+ return joinrel;
+}
+
+RelOptInfo *
+fill_partition_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, RelOptInfo *parent_joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist,
+ List *join_aris)
+{
+ List *tmp_exprs;
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(rel1->reloptkind) && IS_OTHER_REL(rel2->reloptkind));
+
+ joinrel->parent_relids = bms_copy(parent_joinrel->relids);
+
+ /* Computer information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, rel1, rel2);
+
+ /*
+ * Produce partition-wise joinrel's targetlist by translating the parent
+ * joinrel's targetlist. This will also include the required placeholder
+ * Vars.
+ */
+ joinrel->reltarget = copy_pathtarget(parent_joinrel->reltarget);
+ tmp_exprs = joinrel->reltarget->exprs;
+ joinrel->reltarget->exprs = (List *) adjust_partitionrel_attrs(root, (Node *) tmp_exprs,
+ join_aris);
+
+ /*
+ * Lateral relids directly referred in this relation will be same as that
+ * of the parent relation.
+ */
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ joinrel->joininfo = (List *) adjust_partitionrel_attrs(root,
+ (Node *) parent_joinrel->joininfo,
+ join_aris);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /*
+ * Set estimates of the joinrel's size.
+ */
+ set_joinrel_size_estimates(root, joinrel, rel1, rel2, sjinfo,
+ restrictlist);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ return joinrel;
+}
+
/*
* min_join_parameterization
*
* Determine the minimum possible parameterization of a joinrel, that is, the
* set of other rels it contains LATERAL references to. We save this value in
* the join's RelOptInfo. This function is split out of build_join_rel()
* because join_is_legal() needs the value to check a prospective join.
*/
Relids
min_join_parameterization(PlannerInfo *root,
@@ -1313,10 +1435,196 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
ppi->ppi_req_outer = required_outer;
ppi->ppi_rows = 0;
ppi->ppi_clauses = NIL;
appendrel->ppilist = lappend(appendrel->ppilist, ppi);
return ppi;
}
+
+/*
+ * build_partition_info
+ *
+ * Retrieves partitioning information for given relation.
+ *
+ * The function also builds the RelOptInfos of the partitions recursively.
+ * TODO: complete the prologue.
+ */
+static PartitionOptInfo *
+build_partition_info(PlannerInfo *root, RelOptInfo *rel)
+{
+ Relation relation;
+ PartitionKey part_key;
+ PartitionDesc part_desc;
+ PartitionOptInfo *part_info;
+ RangeTblEntry *rte;
+ ListCell *lc;
+ int num_pkexprs;
+ int cnt_pke;
+ int nparts;
+ int cnt_parts;
+ Expr *pkexpr;
+
+ /* The given relation should be simple relation. */
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ Assert(rel->relid != 0);
+
+ rte = root->simple_rte_array[rel->relid];
+ Assert(rte);
+
+ /*
+ * If it's not parent of the inheritance hierarchy, it can not be
+ * partiioned relation.
+ */
+ if (!rte->inh)
+ return NULL;
+
+ /*
+ * We need not lock the relation since it was already locked, either
+ * by the rewriter or when expand_inherited_rtentry() added it to
+ * the query's rangetable.
+ */
+ relation = heap_open(rte->relid, NoLock);
+ part_desc = RelationGetPartitionDesc(relation);
+ part_key = RelationGetPartitionKey(relation);
+
+ /* Nothing to do for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ {
+ heap_close(relation, NoLock);
+ return NULL;
+ }
+
+ part_info = makeNode(PartitionOptInfo);
+
+ /* Store partition descriptor information. */
+ nparts = part_info->nparts = part_desc->nparts;
+ /* TODO: Should we copy the contents of the these arrays? */
+ part_info->lists = (PartitionListInfo **) palloc(sizeof(PartitionListInfo *) * nparts);
+ part_info->ranges = (PartitionRangeInfo **) palloc(sizeof(PartitionRangeInfo *) * nparts);
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ part_info->lists[cnt_parts] = part_desc->parts[cnt_parts]->list;
+ part_info->ranges[cnt_parts] = part_desc->parts[cnt_parts]->range;
+ }
+
+ /* Store partition key information. */
+ part_info->strategy = part_key->strategy;
+ part_info->partnatts = part_key->partnatts;
+ num_pkexprs = part_info->partnatts;
+ /* TODO: Should we copy the contents of these arrays? */
+ part_info->partopfamily = part_key->partopfamily;
+ part_info->partopcintype = part_key->partopcintype;
+ part_info->partsupfunc = part_key->partsupfunc;
+ part_info->tcinfo = part_key->tcinfo;
+
+ /* Store partition keys as single elements lists. */
+ part_info->partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(rel->relid, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (!lc)
+ elog(ERROR, "wrong number of partition key expressions");
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, rel->relid, 0);
+ lc = lnext(lc);
+ }
+
+ part_info->partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ /* Find RelOptInfo of the partitions. */
+ part_info->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) *
+ nparts);
+ foreach(lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(lc);
+ int childRTindex = appinfo->child_relid;
+ RangeTblEntry *childRTE = root->simple_rte_array[childRTindex];
+ RelOptInfo *childrel = root->simple_rel_array[childRTindex];
+
+ /* append_rel_list contains all append rels; ignore others */
+ if (appinfo->parent_relid != rel->relid)
+ continue;
+
+ /* If we haven't created a RelOptInfo aleady, create one. */
+ if (!childrel)
+ childrel = build_simple_rel(root, childRTindex,
+ RELOPT_OTHER_MEMBER_REL);
+
+ /* Save the parent relids for parameterized path handling. */
+ childrel->parent_relids = bms_copy(rel->relids);
+
+ /*
+ * OIDs of the partitions are arranged to match the partition bounds or
+ * list in corresponding arrays. Arrange RelOptInfo's of partitions in
+ * the same fashion.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (part_desc->parts[cnt_parts]->oid == childRTE->relid)
+ {
+ /* Every partition can be seen only once. */
+ Assert(!part_info->part_rels[cnt_parts]);
+ part_info->part_rels[cnt_parts] = childrel;
+
+ break;
+ }
+ }
+ }
+
+ heap_close(relation, NoLock);
+
+ /* We must have found RelOptInfos of all the partitions. */
+ for (cnt_parts = 0; cnt_parts < part_info->nparts; cnt_parts++)
+ Assert(part_info->part_rels[cnt_parts]);
+
+ return part_info;
+}
+
+/*
+ * Adds given join relation to the joinrel list and also to the hashtable if
+ * there is one.
+ */
+void
+add_joinrel_to_list(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 56943f2..16b2eac 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3405,21 +3405,23 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
else
{
/* not time to process varinfo2 yet */
newvarinfos = lcons(varinfo2, newvarinfos);
}
}
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
if (rel->tuples > 0)
{
/*
* Clamp to size of rel, or size of rel / 10 if multiple Vars. The
* fudge factor is because the Vars are probably correlated but we
* don't know by how much. We should never clamp to less than the
* largest ndistinct value for any of the Vars, though, since
* there will surely be at least that many groups.
*/
double clamp = rel->tuples;
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index c5178f7..3412eae 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -870,20 +870,29 @@ static struct config_bool ConfigureNamesBool[] =
},
{
{"enable_hashjoin", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of hash join plans."),
NULL
},
&enable_hashjoin,
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
gettext_noop("Enables genetic query optimization."),
gettext_noop("This algorithm attempts to do planning without "
"exhaustive searching.")
},
&enable_geqo,
true,
NULL, NULL, NULL
diff --git a/src/include/catalog/partition.h b/src/include/catalog/partition.h
index 14fd29e..8b928a3 100644
--- a/src/include/catalog/partition.h
+++ b/src/include/catalog/partition.h
@@ -12,22 +12,88 @@
*/
#ifndef PARTITION_H
#define PARTITION_H
#include "fmgr.h"
#include "executor/tuptable.h"
#include "nodes/execnodes.h"
#include "parser/parse_node.h"
#include "utils/relcache.h"
+/* Type and collation information for partition key columns */
+typedef struct KeyTypeCollInfo
+{
+ Oid *typid;
+ int32 *typmod;
+ int16 *typlen;
+ bool *typbyval;
+ char *typalign;
+ Oid *typcoll;
+} KeyTypeCollInfo;
+
+/*
+ * Partition key information
+ */
+typedef struct PartitionKeyData
+{
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ AttrNumber *partattrs; /* partition attnums */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ FmgrInfo *partsupfunc; /* lookup info for support funcs */
+ List *partexprs; /* partition key expressions, if any */
+ char **partcolnames; /* partition key column names */
+ KeyTypeCollInfo *tcinfo; /* type and collation info (all columns) */
+} PartitionKeyData;
+
typedef struct PartitionKeyData *PartitionKey;
+/* Internal representation of a list partition bound */
+typedef struct PartitionListInfo
+{
+ int nvalues; /* number of values in the following array */
+ Datum *values; /* values contained in the list */
+ bool *nulls;
+} PartitionListInfo;
+
+/*
+ * TODO: the patch by Amit L named this structure as RangeBound, but that
+ * conflicts with a structure with the same name in rangetypes.h. Hence renamed
+ * it here. It should be changed to whatever Amit L uses in the next set of
+ * patches.
+ */
+/* Internal representation of a range partition bound */
+typedef struct PartitionRangeBound
+{
+ Datum *val; /* the bound value, if any */
+ bool infinite; /* bound is +/- infinity */
+ bool inclusive; /* bound is inclusive (vs exclusive) */
+ bool lower; /* this is the lower (vs upper) bound */
+} PartitionRangeBound;
+
+typedef struct PartitionRangeInfo
+{
+ PartitionRangeBound *lower;
+ PartitionRangeBound *upper;
+} PartitionRangeInfo;
+
+/*
+ * Information about a single partition
+ */
+typedef struct PartitionInfoData
+{
+ Oid oid; /* partition OID */
+ PartitionListInfo *list; /* list partition info */
+ PartitionRangeInfo *range; /* range partition info */
+} PartitionInfoData;
+
/*
* Information about partitions of a partitioned table.
*/
typedef struct PartitionInfoData *PartitionInfo;
typedef struct PartitionDescData
{
int nparts; /* Number of partitions */
PartitionInfo *parts; /* Array of PartitionInfoData pointers */
} PartitionDescData;
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index bb62112..4bb5966 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -218,20 +218,21 @@ typedef enum NodeTag
T_DomainConstraintState,
/*
* TAGS FOR PLANNER NODES (relation.h)
*/
T_PlannerInfo = 500,
T_PlannerGlobal,
T_RelOptInfo,
T_IndexOptInfo,
T_ForeignKeyOptInfo,
+ T_PartitionOptInfo,
T_ParamPathInfo,
T_Path,
T_IndexPath,
T_BitmapHeapPath,
T_BitmapAndPath,
T_BitmapOrPath,
T_TidPath,
T_SubqueryScanPath,
T_ForeignPath,
T_CustomPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 2709cc7..fae6c1a 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -12,20 +12,21 @@
*-------------------------------------------------------------------------
*/
#ifndef RELATION_H
#define RELATION_H
#include "access/sdir.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "storage/block.h"
+#include "catalog/partition.h"
/*
* Relids
* Set of relation identifiers (indexes into the rangetable).
*/
typedef Bitmapset *Relids;
/*
* When looking for a "cheapest path", this enum specifies whether we want
@@ -345,20 +346,26 @@ typedef struct PlannerInfo
* is present in the query join tree but the members are not. The member
* RTEs and otherrels are used to plan the scans of the individual tables or
* subqueries of the append set; then the parent baserel is given Append
* and/or MergeAppend paths comprising the best paths for the individual
* member rels. (See comments for AppendRelInfo for more information.)
*
* At one time we also made otherrels to represent join RTEs, for use in
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing pair-wise joins between partitions of
+ * partitioned tables. These relations are not added to join_rel_level lists
+ * as they are not joined directly by the dynamic programming algorithm.
+ * Adding these two join_rel_level list also means that top level list has more
+ * than one join relation, which is symantically incorrect.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
* fields always hold Paths showing ways to do that processing step.
*
* Lastly, there is a RelOptKind for "dead" relations, which are base rels
* that we have proven we don't need to join after all.
*
* Parts of this data structure are specific to various scan and join
* mechanisms. It didn't seem worth creating new node types for them.
@@ -464,24 +471,31 @@ typedef struct PlannerInfo
* We store baserestrictcost in the RelOptInfo (for base relations) because
* we know we will need it at least once (to price the sequential scan)
* and may need it multiple times to price index scans.
*----------
*/
typedef enum RelOptKind
{
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(reloptkind) \
+ ((reloptkind) == RELOPT_OTHER_MEMBER_REL || \
+ (reloptkind) == RELOPT_OTHER_JOINREL)
+
+typedef struct PartitionOptInfo PartitionOptInfo;
+
typedef struct RelOptInfo
{
NodeTag type;
RelOptKind reloptkind;
/* all relations included in this RelOptInfo */
Relids relids; /* set of base relids (rangetable indexes) */
/* size estimates generated by planner */
@@ -535,20 +549,29 @@ typedef struct RelOptInfo
struct FdwRoutine *fdwroutine;
void *fdw_private;
/* used by various scans and joins: */
List *baserestrictinfo; /* RestrictInfo structures (if base
* rel) */
QualCost baserestrictcost; /* cost of evaluating the above */
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations, joins or base relations. NULL otherwise. */
+ /*
+ * TODO: Notice recursive usage of RelOptInfo.
+ */
+ PartitionOptInfo *part_info;
+
+ /* Set only for "other" base or join relations. */
+ Relids parent_relids;
} RelOptInfo;
/*
* IndexOptInfo
* Per-index information for planning/optimization
*
* indexkeys[], indexcollations[], opfamily[], and opcintype[]
* each have ncolumns entries.
*
* sortopfamily[], reverse_sort[], and nulls_first[] likewise have
@@ -649,20 +672,45 @@ typedef struct ForeignKeyOptInfo
/* Derived info about whether FK's equality conditions match the query: */
int nmatched_ec; /* # of FK cols matched by ECs */
int nmatched_rcols; /* # of FK cols matched by non-EC rinfos */
int nmatched_ri; /* total # of non-EC rinfos matched to FK */
/* Pointer to eclass matching each column's condition, if there is one */
struct EquivalenceClass *eclass[INDEX_MAX_KEYS];
/* List of non-EC RestrictInfos matching each column's condition */
List *rinfos[INDEX_MAX_KEYS];
} ForeignKeyOptInfo;
+/*
+ * PartitionOptInfo
+ * Partitioning information for planning/optimization
+ *
+ * TODO: complete the comment
+ */
+typedef struct PartitionOptInfo
+{
+ NodeTag type;
+
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ RelOptInfo **part_rels; /* RelOptInfos of partitions */
+ PartitionListInfo **lists; /* list bounds */
+ PartitionRangeInfo **ranges; /* range lower bounds */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ List **partexprs; /* partition key expressions. */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ FmgrInfo *partsupfunc; /* lookup info for support funcs */
+ KeyTypeCollInfo *tcinfo; /* type and collation info (all columns) */
+} PartitionOptInfo;
/*
* EquivalenceClasses
*
* Whenever we can determine that a mergejoinable equality clause A = B is
* not delayed by any outer join, we create an EquivalenceClass containing
* the expressions A and B to record this knowledge. If we later find another
* equivalence B = C, we add C to the existing EquivalenceClass; this may
* require merging two existing EquivalenceClasses. At the end of the qual
* distribution process, we have sets of values that are known all transitively
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..1069726 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -59,20 +59,21 @@ extern bool enable_seqscan;
extern bool enable_indexscan;
extern bool enable_indexonlyscan;
extern bool enable_bitmapscan;
extern bool enable_tidscan;
extern bool enable_sort;
extern bool enable_hashagg;
extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
double index_pages, PlannerInfo *root);
extern void cost_seqscan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_samplescan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_index(IndexPath *path, PlannerInfo *root,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 71d9154..5a4b054 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -222,20 +222,22 @@ extern ModifyTablePath *create_modifytable_path(PlannerInfo *root,
List *rowMarks, OnConflictExpr *onconflict,
int epqParam);
extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_for_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
*/
extern void setup_simple_rel_arrays(PlannerInfo *root);
extern RelOptInfo *build_simple_rel(PlannerInfo *root, int relid,
RelOptKind reloptkind);
extern RelOptInfo *find_base_rel(PlannerInfo *root, int relid);
extern RelOptInfo *find_join_rel(PlannerInfo *root, Relids relids);
extern RelOptInfo *build_join_rel(PlannerInfo *root,
@@ -260,12 +262,20 @@ extern ParamPathInfo *get_baserel_parampathinfo(PlannerInfo *root,
Relids required_outer);
extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
RelOptInfo *joinrel,
Path *outer_path,
Path *inner_path,
SpecialJoinInfo *sjinfo,
Relids required_outer,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *make_joinrel(PlannerInfo *root, RelOptKind reloptkind,
+ Relids joinrelids);
+extern RelOptInfo *fill_partition_join_rel(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ RelOptInfo *parent_joinrel,
+ SpecialJoinInfo *sjinfo,
+ List *restrictlist, List *join_aris);
+extern void add_joinrel_to_list(PlannerInfo *root, RelOptInfo *joinrel);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..152db2b 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -212,11 +212,14 @@ extern List *make_inner_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
List *outer_pathkeys);
extern List *truncate_useless_pathkeys(PlannerInfo *root,
RelOptInfo *rel,
List *pathkeys);
extern bool has_useful_pathkeys(PlannerInfo *root, RelOptInfo *rel);
extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+/* TODO: need a better place to save this function signature. */
+extern Relids adjust_partition_relids(Relids relids, List *append_rel_infos);
+
#endif /* PATHS_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index fb35b68..7b149c3 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -21,20 +21,23 @@
/*
* prototypes for prepjointree.c
*/
extern void pull_up_sublinks(PlannerInfo *root);
extern void inline_set_returning_functions(PlannerInfo *root);
extern void pull_up_subqueries(PlannerInfo *root);
extern void flatten_simple_union_all(PlannerInfo *root);
extern void reduce_outer_joins(PlannerInfo *root);
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
+extern Node *adjust_partitionrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos);
+extern List *find_appendrelinfos_by_relids(PlannerInfo *root, Relids relids);
/*
* prototypes for prepqual.c
*/
extern Node *negate_clause(Node *node);
extern Expr *canonicalize_qual(Expr *qual);
/*
* prototypes for prepsecurity.c
*/
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..307076e
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,6838 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (((t1.a + t1.b) / 2) = ((t2.b + t2.a) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: (((t1_1.a + t1_1.b) / 2) = ((t2_1.b + t2_1.a) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: (((t1_2.a + t1_2.b) / 2) = ((t2_2.b + t2_2.a) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Sort Key: prt1_e_p1.a, prt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Hash Cond: (((prt1_e_p1.a + prt1_e_p1.b) / 2) = ((prt2_e_p1.b + prt2_e_p1.a) / 2))
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt1_e_p1.b
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ -> Seq Scan on public.prt2_e_p1
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ Filter: ((prt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt2_e_p2.b, prt2_e_p2.c
+ Hash Cond: (((prt1_e_p2.a + prt1_e_p2.b) / 2) = ((prt2_e_p2.b + prt2_e_p2.a) / 2))
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt1_e_p2.b
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ -> Seq Scan on public.prt2_e_p2
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ Filter: ((prt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt2_e_p3.b, prt2_e_p3.c
+ Hash Cond: (((prt1_e_p3.a + prt1_e_p3.b) / 2) = ((prt2_e_p3.b + prt2_e_p3.a) / 2))
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt1_e_p3.b
+ Filter: ((prt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ -> Seq Scan on public.prt2_e_p3
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ Filter: ((prt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t2.a, t2.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t2_1.a, t2_1.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t2_2.a, t2_2.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Append
+ -> Seq Scan on public.prt2_l t2
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_6
+ Output: t2_6.b, t2_6.c, t2_6.a
+ -> Seq Scan on public.prt2_l_p3 t2_7
+ Output: t2_7.b, t2_7.c, t2_7.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_8
+ Output: t2_8.b, t2_8.c, t2_8.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_9
+ Output: t2_9.b, t2_9.c, t2_9.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Append
+ -> Seq Scan on public.prt1_l t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p1 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p2 t1_6
+ Output: t1_6.a, t1_6.c, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3 t1_7
+ Output: t1_7.a, t1_7.c, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_8
+ Output: t1_8.a, t1_8.c, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_9
+ Output: t1_9.a, t1_9.c, t1_9.b
+ Filter: ((t1_9.a % 25) = 0)
+(60 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Append
+ -> Seq Scan on public.prt2_l t2
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_6
+ Output: t2_6.b, t2_6.c, t2_6.a
+ -> Seq Scan on public.prt2_l_p3 t2_7
+ Output: t2_7.b, t2_7.c, t2_7.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_8
+ Output: t2_8.b, t2_8.c, t2_8.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_9
+ Output: t2_9.b, t2_9.c, t2_9.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Append
+ -> Seq Scan on public.prt1_l t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p1 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p2 t1_6
+ Output: t1_6.a, t1_6.c, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3 t1_7
+ Output: t1_7.a, t1_7.c, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_8
+ Output: t1_8.a, t1_8.c, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_9
+ Output: t1_9.a, t1_9.c, t1_9.b
+ Filter: ((t1_9.a % 25) = 0)
+(60 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
+ -> Append
+ -> Seq Scan on public.prt1_l t1
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_6
+ Output: t1_6.a, t1_6.c, t1_6.b
+ -> Seq Scan on public.prt1_l_p3 t1_7
+ Output: t1_7.a, t1_7.c, t1_7.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_8
+ Output: t1_8.a, t1_8.c, t1_8.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_9
+ Output: t1_9.a, t1_9.c, t1_9.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Append
+ -> Seq Scan on public.prt2_l t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: ((t2_3.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: ((t2_4.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2_p1 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: ((t2_5.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2_p2 t2_6
+ Output: t2_6.b, t2_6.c, t2_6.a
+ Filter: ((t2_6.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3 t2_7
+ Output: t2_7.b, t2_7.c, t2_7.a
+ Filter: ((t2_7.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p1 t2_8
+ Output: t2_8.b, t2_8.c, t2_8.a
+ Filter: ((t2_8.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p2 t2_9
+ Output: t2_9.b, t2_9.c, t2_9.a
+ Filter: ((t2_9.b % 25) = 0)
+(60 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l.a, prt1_l.c, prt2_l.b, prt2_l.c
+ Sort Key: prt1_l.a, prt2_l.b
+ -> Hash Full Join
+ Output: prt1_l.a, prt1_l.c, prt2_l.b, prt2_l.c
+ Hash Cond: ((prt1_l.a = prt2_l.b) AND (prt1_l.b = prt2_l.a) AND ((prt1_l.c)::text = (prt2_l.c)::text) AND ((prt1_l.b + prt1_l.a) = (prt2_l.a + prt2_l.b)))
+ -> Append
+ -> Seq Scan on public.prt1_l
+ Output: prt1_l.a, prt1_l.c, prt1_l.b
+ Filter: ((prt1_l.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1
+ Output: prt1_l_p1.a, prt1_l_p1.c, prt1_l_p1.b
+ Filter: ((prt1_l_p1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2
+ Output: prt1_l_p2.a, prt1_l_p2.c, prt1_l_p2.b
+ Filter: ((prt1_l_p2.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3
+ Output: prt1_l_p3.a, prt1_l_p3.c, prt1_l_p3.b
+ Filter: ((prt1_l_p3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l.b, prt2_l.c, prt2_l.a
+ -> Append
+ -> Seq Scan on public.prt2_l
+ Output: prt2_l.b, prt2_l.c, prt2_l.a
+ Filter: ((prt2_l.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1
+ Output: prt2_l_p1.b, prt2_l_p1.c, prt2_l_p1.a
+ Filter: ((prt2_l_p1.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2
+ Output: prt2_l_p2.b, prt2_l_p2.c, prt2_l_p2.a
+ Filter: ((prt2_l_p2.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3
+ Output: prt2_l_p3.b, prt2_l_p3.c, prt2_l_p3.a
+ Filter: ((prt2_l_p3.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.c = t1.c) AND (t2.a = t1.a))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.c = t1_1.c) AND (t2_1.a = t1_1.a))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.c = t1_2.c) AND (t2_2.a = t1_2.a))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, avg(plt2_p1.b), plt2_p1.c
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, sum((25)), avg(plt2_p1.b), plt2_p1.c, avg((50))
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (25), (50)
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c, 25
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c, (50)
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c, 50
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, (25), (50)
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c, 25
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c, (50)
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c, 50
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, (25), (50)
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c, 25
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c, (50)
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c, 50
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (avg(t2.b)), t2.c
+ Sort Key: t1.c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, avg(t2.b), t2.c
+ Group Key: t1.c, t2.c
+ -> Result
+ Output: t1.c, t2.c, t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(20 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Left Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Left Join
+ Output: t1_1.a, t1_1.c, t2.b, t2.c
+ Hash Cond: (t1_1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(a)), c, (sum(t2.b)), t2.c
+ Sort Key: c, t2.c
+ -> HashAggregate
+ Output: sum(a), c, sum(t2.b), t2.c
+ Group Key: c, t2.c
+ -> Result
+ Output: c, t2.c, a, t2.b
+ -> Append
+ -> Hash Left Join
+ Output: t2.b, t2.c, a, c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1.a, t1.c
+ Hash Cond: (t1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (ltrim(t1.c, 'A'::text) = ltrim(t2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (ltrim(t1_1.c, 'A'::text) = ltrim(t2_1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (ltrim(t1_2.c, 'A'::text) = ltrim(t2_2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Sort Key: plt1_e_p1.a, plt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Hash Cond: ((plt1_e_p1.a = plt2_e_p1.b) AND (ltrim(plt1_e_p1.c, 'A'::text) = ltrim(plt2_e_p1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ -> Seq Scan on public.plt2_e_p1
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ Filter: ((plt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p2.a, plt1_e_p2.c, plt2_e_p2.b, plt2_e_p2.c
+ Hash Cond: ((plt1_e_p2.a = plt2_e_p2.b) AND (ltrim(plt1_e_p2.c, 'A'::text) = ltrim(plt2_e_p2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ -> Seq Scan on public.plt2_e_p2
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ Filter: ((plt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p3.a, plt1_e_p3.c, plt2_e_p3.b, plt2_e_p3.c
+ Hash Cond: ((plt1_e_p3.a = plt2_e_p3.b) AND (ltrim(plt1_e_p3.c, 'A'::text) = ltrim(plt2_e_p3.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ -> Seq Scan on public.plt2_e_p3
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ Filter: ((plt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((t3.a = t2.b) AND ((ltrim(t3.c, 'A'::text)) = t2.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (ltrim(t3.c, 'A'::text))
+ Sort Key: t3.a, (ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ltrim(t3.c, 'A'::text)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((t3_1.a = t2_1.b) AND ((ltrim(t3_1.c, 'A'::text)) = t2_1.c))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (ltrim(t3_1.c, 'A'::text))
+ Sort Key: t3_1.a, (ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ltrim(t3_1.c, 'A'::text)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((t3_2.a = t2_2.b) AND ((ltrim(t3_2.c, 'A'::text)) = t2_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (ltrim(t3_2.c, 'A'::text))
+ Sort Key: t3_2.a, (ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ltrim(t3_2.c, 'A'::text)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: ((ltrim(t1_6.c, 'A'::text)) = t1_3.c)
+ -> Sort
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Sort Key: (ltrim(t1_6.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Sort
+ Output: t1_3.c
+ Sort Key: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: ((ltrim(t1_7.c, 'A'::text)) = t1_4.c)
+ -> Sort
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Sort Key: (ltrim(t1_7.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Sort
+ Output: t1_4.c
+ Sort Key: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: ((ltrim(t1_8.c, 'A'::text)) = t1_5.c)
+ -> Sort
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Sort Key: (ltrim(t1_8.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+ -> Sort
+ Output: t1_5.c
+ Sort Key: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+(88 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (ltrim(t3.c, 'A'::text) = t2.c)
+ Join Filter: (t2.b = t3.a)
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iplt2_p1_c on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (ltrim(t3_1.c, 'A'::text) = t2_1.c)
+ Join Filter: (t2_1.b = t3_1.a)
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iplt2_p2_c on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: (ltrim(t3_2.c, 'A'::text) = t2_2.c)
+ Join Filter: (t2_2.b = t3_2.a)
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iplt2_p3_c on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Index Scan using iplt2_p1_c on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Index Scan using iplt1_p2_c on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Index Scan using iplt2_p2_c on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Index Scan using iplt2_p3_c on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Semi Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Index Only Scan using iplt2_p1_c on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Materialize
+ Output: t1_6.c
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t1_6
+ Output: t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Semi Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Index Only Scan using iplt2_p2_c on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Materialize
+ Output: t1_7.c
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t1_7
+ Output: t1_7.c
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Semi Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Index Only Scan using iplt2_p3_c on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Materialize
+ Output: t1_8.c
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t1_8
+ Output: t1_8.c
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- negative testcases
+--
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out
index f06cfa4..16e7f56 100644
--- a/src/test/regress/expected/rangefuncs.out
+++ b/src/test/regress/expected/rangefuncs.out
@@ -1,25 +1,26 @@
SELECT name, setting FROM pg_settings WHERE name LIKE 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
CREATE TABLE foo2(fooid int, f2 int);
INSERT INTO foo2 VALUES(1, 11);
INSERT INTO foo2 VALUES(2, 22);
INSERT INTO foo2 VALUES(1, 111);
CREATE FUNCTION foot(int) returns setof foo2 as 'SELECT * FROM foo2 WHERE fooid = $1 ORDER BY f2;' LANGUAGE SQL;
-- function with ORDINALITY
select * from foot(1) with ordinality as z(a,b,ord);
a | b | ord
---+-----+-----
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 1cb5dfc..d62841d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -93,21 +93,21 @@ test: alter_generic alter_operator misc psql async dbsize misc_functions
# rules cannot run concurrently with any test that creates a view
test: rules psql_crosstab amutils
# run by itself so it can run parallel workers
test: select_parallel
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
# so keep this parallel group to at most 19 tests
# ----------
test: plancache limit plpgsql copy2 temp domain rangefuncs prepare without_oid conversion truncate alter_table sequence polymorphism rowtypes returning largeobject with xml
# event triggers cannot run concurrently with any test that runs DDL
test: event_trigger
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 8958d8c..49a27b1 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -161,10 +161,11 @@ test: truncate
test: alter_table
test: sequence
test: polymorphism
test: rowtypes
test: returning
test: largeobject
test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..19c7d29
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,746 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- negative testcases
+--
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
On Fri, Sep 9, 2016 at 3:17 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
4. Remove bms_to_char(): I have added this function to print Relids in the
debugger. I have found it very useful to quickly examine Relids in debugger,
which otherwise wasn't so easy. If others find it useful too, I can create a
separate patch to be considered for a separate commit.
+1 to have such a function. I often need something like that whenever
I debug the optimizer code.
--
With Regards,
Amit Kapila.
EnterpriseDB: http://www.enterprisedb.com
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On 2016/09/09 18:47, Ashutosh Bapat wrote:
A related change is renaming RangeBound structure in Amit
Langote's patches to PartitionRangeBound to avoid name conflict with
rangetypes.h. That change too should vanish once we decide where to keep
that structure and its final name.
This change has been incorporated into the latest patch I posted on Sep 9 [1]/messages/by-id/28ee345c-1278-700e-39a7-36a71f9a3b43@lab.ntt.co.jp.
Thanks,
Amit
[1]: /messages/by-id/28ee345c-1278-700e-39a7-36a71f9a3b43@lab.ntt.co.jp
/messages/by-id/28ee345c-1278-700e-39a7-36a71f9a3b43@lab.ntt.co.jp
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Fri, Sep 9, 2016 at 3:17 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
Hi All,
PFA the patch to support partition-wise joins for partitioned tables. The
patch
is based on the declarative parition support patches provided by Amit
Langote
on 26th August 2016.
I have applied declarative partitioning patches posted by Amit Langote on
26 Aug 2016 and then partition-wise-join patch, getting below error while
make install.
../../../../src/include/nodes/relation.h:706: error: redefinition of
typedef ‘PartitionOptInfo’
../../../../src/include/nodes/relation.h:490: note: previous declaration of
‘PartitionOptInfo’ was here
make[4]: *** [gistbuild.o] Error 1
make[4]: Leaving directory `/home/edb/Desktop/edb_work/WO
RKDB/PG/postgresql/src/backend/access/gist'
make[3]: *** [gist-recursive] Error 2
make[3]: Leaving directory `/home/edb/Desktop/edb_work/WO
RKDB/PG/postgresql/src/backend/access'
make[2]: *** [access-recursive] Error 2
make[2]: Leaving directory `/home/edb/Desktop/edb_work/WO
RKDB/PG/postgresql/src/backend'
make[1]: *** [all-backend-recurse] Error 2
make[1]: Leaving directory `/home/edb/Desktop/edb_work/WO
RKDB/PG/postgresql/src'
make: *** [all-src-recurse] Error 2
PS : I am using - gcc (GCC) 4.4.7 20120313 (Red Hat 4.4.7-17)
Attached the patch for the fix of above error.
Thanks & Regards,
Rajkumar Raghuwanshi
QMG, EnterpriseDB Corporation
Attachments:
pwj_install_fix.patchtext/x-patch; charset=US-ASCII; name=pwj_install_fix.patchDownload
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 1e9fed9..963b022 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -487,7 +487,7 @@ typedef enum RelOptKind
((reloptkind) == RELOPT_OTHER_MEMBER_REL || \
(reloptkind) == RELOPT_OTHER_JOINREL)
-typedef struct PartitionOptInfo PartitionOptInfo;
+typedef struct PartitionOptInfo;
typedef struct RelOptInfo
{
@@ -561,7 +561,7 @@ typedef struct RelOptInfo
/*
* TODO: Notice recursive usage of RelOptInfo.
*/
- PartitionOptInfo *part_info;
+ struct PartitionOptInfo *part_info;
/* Set only for "other" base or join relations. */
Relids parent_relids;
On Fri, Sep 16, 2016 at 6:00 PM, Rajkumar Raghuwanshi
<rajkumar.raghuwanshi@enterprisedb.com> wrote:
On Fri, Sep 9, 2016 at 3:17 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Hi All,
PFA the patch to support partition-wise joins for partitioned tables. The
patch
is based on the declarative parition support patches provided by Amit
Langote
on 26th August 2016.I have applied declarative partitioning patches posted by Amit Langote on 26
Aug 2016 and then partition-wise-join patch, getting below error while make
install.../../../../src/include/nodes/relation.h:706: error: redefinition of typedef
‘PartitionOptInfo’
../../../../src/include/nodes/relation.h:490: note: previous declaration of
‘PartitionOptInfo’ was here
make[4]: *** [gistbuild.o] Error 1
make[4]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src/backend/access/gist'
make[3]: *** [gist-recursive] Error 2
make[3]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src/backend/access'
make[2]: *** [access-recursive] Error 2
make[2]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src/backend'
make[1]: *** [all-backend-recurse] Error 2
make[1]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src'
make: *** [all-src-recurse] Error 2PS : I am using - gcc (GCC) 4.4.7 20120313 (Red Hat 4.4.7-17)
Attached the patch for the fix of above error.
Thanks for the report. I will fix this in the next patch.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
PFA patch which takes care of some of the TODOs mentioned in my
previous mail. The patch is based on the set of patches supporting
declarative partitioning by Amit Langoted posted on 26th August.
TODOs:
1. Instead of storing partitioning information in RelOptInfo of each of the
partitioned relations (base and join relations), we can keep a list of
canonical partition schemes in PlannerInfo. Every RelOptInfo gets a pointer
to
the member of list representing the partitioning scheme of corresponding
relation. RelOptInfo's of all similarly partitioned relations get the same
pointer thus making it easy to match the partitioning schemes by comparing
the
pointers. While we are supporting only exact partition matching scheme now,
it's possible to extend this method to match compatible partitioning schemes
by
maintaining a list of compatible partitioning schemes.Right now, I have moved some partition related structures from partition.c
to
partition.h. These structures are still being reviewed and might change when
Amit Langote improves his patches. Having canonical partitioning scheme in
PlannerInfo may not require moving those structures out. So, that code is
still
under development. A related change is renaming RangeBound structure in Amit
Langote's patches to PartitionRangeBound to avoid name conflict with
rangetypes.h. That change too should vanish once we decide where to keep
that
structure and its final name.
Done.
2. Multi-level partitioned tables: For some reason path created for joining
partitions are not being picked up as the cheapest paths. I think, we need
to
finalize the lower level paths before moving upwards in the partition
hierarchy. But I am yet to investigate the issue here.
RelOptInfo::parent_relid
should point to top parents rather than immediate parents.
Done
3. Testing: need more tests for testing partition-wise join with foreign
tables
as partitions. More tests for parameterized joins for multi-level
partitioned
joins.
Needs to be done.
4. Remove bms_to_char(): I have added this function to print Relids in the
debugger. I have found it very useful to quickly examine Relids in debugger,
which otherwise wasn't so easy. If others find it useful too, I can create a
separate patch to be considered for a separate commit.
I will take care of this after rebasing the patch on the latest
sources and latest set of patches by Amit Langote.
5. In add_paths_to_append_rel() to find the possible set of outer relations
for
generating parameterized paths for a given join. This code needs to be
adjusted
to eliminate the parent relations possible set of outer relations for a join
between child partitions.
Done.
6. Add support to reparameterize more types of paths for child relations. I
will add this once we finalize the method to reparameterize a parent path
for
child partition.
Will wait for reviewer's opinion.
7. The patch adds make_joinrel() (name needs to be changed because of its
similariy with make_join_rel()) to construct an empty RelOptInfo for a join
between partitions. The function copies code doing the same from
build_join_rel(). build_join_rel() too can use this function, if we decide
to
retain it.
This will be done as a separate cleanup patch.
8. Few small TODOs related to code reorganization, proper function,
variable naming etc. are in the patch. pg_indent run.
I have taken care of most of the TODOs. But there are still some TODOs
remaining. I will take care of those in the next version of patches.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_v2.patchinvalid/octet-stream; name=pg_dp_join_v2.patchDownload
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index f17ac29..4f840c1 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -13,38 +13,41 @@
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/nbtree.h"
#include "access/sysattr.h"
#include "catalog/dependency.h"
+#include "catalog/heap.h"
#include "catalog/indexing.h"
#include "catalog/objectaddress.h"
#include "catalog/partition.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_inherits_fn.h"
#include "catalog/pg_opclass.h"
#include "catalog/pg_partitioned_table.h"
#include "catalog/pg_partitioned_table_fn.h"
#include "catalog/pg_type.h"
#include "executor/executor.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "nodes/parsenodes.h"
#include "optimizer/clauses.h"
+#include "optimizer/cost.h"
#include "optimizer/planmain.h"
#include "optimizer/var.h"
+#include "rewrite/rewriteManip.h"
#include "storage/lmgr.h"
#include "utils/array.h"
#include "utils/builtins.h"
#include "utils/datum.h"
#include "utils/memutils.h"
#include "utils/fmgroids.h"
#include "utils/inval.h"
#include "utils/lsyscache.h"
#include "utils/ruleutils.h"
#include "utils/rel.h"
@@ -158,20 +161,50 @@ typedef struct PartitionTreeNodeData
PartitionDesc pdesc;
Oid relid;
int index;
int offset;
int num_leaf_parts;
struct PartitionTreeNodeData *downlink;
struct PartitionTreeNodeData *next;
} PartitionTreeNodeData;
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting be partitioned in the same as the underlying relations.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ PartitionListInfo **lists; /* list bounds */
+ PartitionRangeInfo **ranges; /* range lower bounds */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
/* Support RelationBuildPartitionKey() */
static PartitionKey copy_partition_key(PartitionKey fromkey);
static KeyTypeCollInfo *copy_key_type_coll_info(int nkeycols,
KeyTypeCollInfo *tcinfo);
/* Support RelationBuildPartitionDesc() */
static int32 partition_cmp(const void *a, const void *b, void *arg);
/* Support check_new_partition_bound() */
static bool list_overlaps_existing_partition(PartitionKey key,
@@ -222,20 +255,23 @@ static int range_partition_for_tuple(PartitionKey key, PartitionDesc pdesc,
/* List partition related support functions */
static PartitionListInfo *make_list_from_spec(PartitionKey key,
PartitionListSpec *list_spec);
static PartitionListInfo *copy_list_info(PartitionListInfo *src,
PartitionKey key);
static bool equal_list_info(PartitionKey key, PartitionListInfo *l1,
PartitionListInfo *l2);
static bool partition_list_values_equal(PartitionKey key,
Datum val1, Datum val2);
+static bool have_same_partition_lists(PartitionDesc part_desc,
+ PartitionKey part_key,
+ PartitionScheme part_scheme);
/* Range partition related support functions */
static PartitionRangeInfo *make_range_from_spec(PartitionKey key,
PartitionRangeSpec *range_spec);
static RangeBound *make_range_bound(PartitionKey key, List *val, bool inclusive,
bool lower);
static PartitionRangeInfo *copy_range_info(PartitionRangeInfo *src,
PartitionKey key);
static RangeBound *copy_range_bound(RangeBound *src, PartitionKey key);
static bool equal_range_info(PartitionKey key, PartitionRangeInfo *r1,
@@ -245,20 +281,23 @@ static int32 partition_range_cmp(PartitionKey key, PartitionRangeInfo *r1,
static int32 partition_range_bound_cmp(PartitionKey key, RangeBound *b1,
RangeBound *b2);
static int32 partition_range_tuple_cmp(PartitionKey key,
Datum *val1, Datum *val2);
static bool partition_range_overlaps(PartitionKey key,
PartitionRangeInfo *r1, PartitionRangeInfo *r2);
static bool tuple_rightof_bound(PartitionKey key, Datum *tuple, RangeBound *bound);
static bool tuple_leftof_bound(PartitionKey key, Datum *tuple, RangeBound *bound);
static int range_partition_bsearch(PartitionKey key, PartitionDesc pdesc,
Datum *tuple);
+static bool have_same_partition_bounds(PartitionDesc part_desc,
+ PartitionKey part_key,
+ PartitionScheme part_scheme);
/*
* Partition key related functions
*/
/*
* RelationBuildPartitionKey
* Build and attach to relcache partition key data of relation
*
* Note that the partition key data attached to a relcache entry must be
@@ -2358,10 +2397,357 @@ tuple_rightof_bound(PartitionKey key, Datum *tuple, RangeBound *bound)
static bool
tuple_leftof_bound(PartitionKey key, Datum *tuple, RangeBound *bound)
{
int32 cmpval = partition_range_tuple_cmp(key, tuple, bound->val);
if (!cmpval)
return !bound->lower ? bound->inclusive : !bound->inclusive;
return cmpval < 0;
}
+
+/*
+ * find_partition_scheme
+ * Find the "canonical" partition scheme for the given base table.
+ *
+ * The function searches the list of canonical partition schemes for one that
+ * exactly matches the partitioning properties of the given relation. If it
+ * does not find one, the function creates a canonical partition scheme
+ * structure and adds it to the list.
+ *
+ * For an umpartitioned table, it returns NULL.
+ */
+extern PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ int cnt_parts;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * It suffices to check the OID of support function as it always has
+ * two arguemnts and returns boolean. For types, it suffices to match
+ * the type id, mod and collation; len, byval and align are depedent on
+ * the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->tcinfo->typid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->tcinfo->typmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->tcinfo->typcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ /* Match partition bounds or lists. */
+ switch (part_scheme->strategy)
+ {
+ case PARTITION_STRAT_LIST:
+ if (!have_same_partition_lists(part_desc, part_key,
+ part_scheme))
+ continue;
+ break;
+
+ case PARTITION_STRAT_RANGE:
+ if (!have_same_partition_bounds(part_desc, part_key,
+ part_scheme))
+ continue;
+ break;
+
+ default:
+ /* Unknown partition strategy. */
+ elog(ERROR, "unknown partition strategy code %d",
+ part_key->strategy);
+ break;
+ }
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ switch (part_scheme->strategy)
+ {
+ case PARTITION_STRAT_LIST:
+ part_scheme->lists = (PartitionListInfo **) palloc(sizeof(PartitionListInfo *) * nparts);
+ part_scheme->ranges = NULL;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ part_scheme->lists[cnt_parts] = copy_list_info(part_desc->parts[cnt_parts]->list,
+ part_key);
+ break;
+
+ case PARTITION_STRAT_RANGE:
+ part_scheme->ranges = (PartitionRangeInfo **) palloc(sizeof(PartitionRangeInfo *) * nparts);
+ part_scheme->lists = NULL;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ part_scheme->ranges[cnt_parts] = copy_range_info(part_desc->parts[cnt_parts]->range,
+ part_key);
+ break;
+
+ default:
+ elog(ERROR, "unknown partition strategy code %d",
+ part_key->strategy);
+ break;
+ }
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ part_scheme->partopfamily[cnt_pks] = part_key->partopfamily[cnt_pks];
+ part_scheme->partopcintype[cnt_pks] = part_key->partopcintype[cnt_pks];
+ part_scheme->key_types[cnt_pks] = part_key->tcinfo->typid[cnt_pks];
+ part_scheme->key_typmods[cnt_pks] = part_key->tcinfo->typmod[cnt_pks];
+ part_scheme->key_collations[cnt_pks] = part_key->tcinfo->typcoll[cnt_pks];
+ }
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * have_same_partition_lists
+ *
+ * For given list partitioned relations, return true if lists for all the
+ * partitions of both the relations match. Return false otherwise.
+ */
+static bool
+have_same_partition_lists(PartitionDesc part_desc, PartitionKey part_key,
+ PartitionScheme part_scheme)
+{
+ int cnt_parts;
+
+ Assert(part_scheme->strategy == part_key->strategy);
+ Assert(part_key->strategy == PARTITION_STRAT_LIST &&
+ part_key->strategy == PARTITION_STRAT_LIST);
+
+ Assert(part_scheme->nparts == part_desc->nparts);
+
+ /* List partition has only one partition key. */
+ Assert(part_key->partnatts == 1 && part_scheme->partnatts == 1);
+
+ for (cnt_parts = 0; cnt_parts < part_desc->nparts; cnt_parts++)
+ {
+ if (!equal_list_info(part_key, part_scheme->lists[cnt_parts],
+ part_desc->parts[cnt_parts]->list))
+ return false;
+ }
+
+ /* Ok, everything matches, return true. */
+ return true;
+}
+
+/*
+ * have_same_partition_bounds
+ *
+ * For given partitioned relations, return true if the bounds of all the
+ * partitions of the both the relations match. Return false otherwise.
+ */
+static bool
+have_same_partition_bounds(PartitionDesc part_desc, PartitionKey part_key,
+ PartitionScheme part_scheme)
+{
+ int cnt_parts;
+ Assert(part_key->strategy == PARTITION_STRAT_RANGE &&
+ part_scheme->strategy == PARTITION_STRAT_RANGE);
+
+ Assert(part_desc->nparts == part_scheme->nparts);
+
+ for (cnt_parts = 0; cnt_parts < part_desc->nparts; cnt_parts++)
+ {
+ if (!equal_range_info(part_key, part_scheme->ranges[cnt_parts],
+ part_desc->parts[cnt_parts]->range))
+ return false;
+ }
+
+ /* Ok, everything matches. */
+ return true;
+}
+
+extern List **
+build_baserel_partition_keys(PlannerInfo *root, Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+
+ /* Store partition keys as single elements lists. */
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+
+ lc = list_head(part_key->partexprs);
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (!lc)
+ elog(ERROR, "wrong number of partition key expressions");
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
+
+/*
+ * Returns the number of partitions supported by the given partition scheme.
+ */
+extern int
+PartitionSchemeGetNumParts(PartitionScheme part_scheme)
+{
+ return part_scheme ? part_scheme->nparts : 0;
+}
+
+/*
+ * Returns the number of partition keys supported by the given partition
+ * scheme.
+ */
+extern int
+PartitionSchemeGetNumKeys(PartitionScheme part_scheme)
+{
+ return part_scheme ? part_scheme->partnatts : 0;
+}
+
+/*
+ * Set up partitioning scheme and partition keys for a join between given two
+ * relations.
+ */
+extern void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /*
+ * Nothing to do if
+ * a. partition-wise join is disabled.
+ * b. joining relations are not partitioned.
+ * c. partitioning schemes do not match.
+ */
+ if (!enable_partition_wise_join ||
+ !outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel and thus we
+ * should not see partition scheme, partition keys and array for storing
+ * child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ num_pks = outer_rel->part_scheme->partnatts;
+
+ /* Join relation is partitioned in the same way as the joining relation. */
+ joinrel->part_scheme = outer_rel->part_scheme;
+
+ /*
+ * Collect the partition key expressions.
+ * TODO: for an outer join we may want to exclude the inner side. For
+ * a FULL OUTER join this means, that it doesn't have any partition
+ * keys.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
+
+/*
+ * Return palloc'ed array of OIDs of partitions.
+ */
+extern Oid *
+PartitionDescGetPartOids(PartitionDesc part_desc)
+{
+ Oid *part_oids;
+ int cnt_parts;
+
+ if (!part_desc || part_desc->nparts <= 0)
+ return NULL;
+
+ part_oids = (Oid *) palloc(sizeof(Oid) * part_desc->nparts);
+ for (cnt_parts = 0; cnt_parts < part_desc->nparts; cnt_parts++)
+ part_oids[cnt_parts] = part_desc->parts[cnt_parts]->oid;
+
+ return part_oids;
+}
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3b8fa6b..cd14840 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -204,20 +204,31 @@ _outBitmapset(StringInfo str, const Bitmapset *bms)
}
/* for use by extensions which define extensible nodes */
void
outBitmapset(StringInfo str, const Bitmapset *bms)
{
_outBitmapset(str, bms);
}
/*
+ * TODO: remove, used for debugging through gdb.
+ */
+char *
+bms_to_char(const Bitmapset *bms)
+{
+ StringInfo str = makeStringInfo();
+ outBitmapset(str, bms);
+ return str->data;
+}
+
+/*
* Print the value of a Datum given its type.
*/
void
outDatum(StringInfo str, Datum value, int typlen, bool typbyval)
{
Size length,
i;
char *s;
length = datumGetSize(value, typbyval, typlen);
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 04264b4..ad6ccf2 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -13,20 +13,21 @@
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include <limits.h>
#include <math.h>
#include "access/sysattr.h"
#include "access/tsmapi.h"
+#include "catalog/partition.h"
#include "catalog/pg_class.h"
#include "catalog/pg_operator.h"
#include "catalog/pg_proc.h"
#include "foreign/fdwapi.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#ifdef OPTIMIZER_DEBUG
#include "nodes/print.h"
#endif
#include "optimizer/clauses.h"
@@ -37,20 +38,21 @@
#include "optimizer/plancat.h"
#include "optimizer/planner.h"
#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "rewrite/rewriteManip.h"
#include "utils/lsyscache.h"
+#include "utils/rel.h"
/* results of subquery_is_pushdown_safe */
typedef struct pushdown_safety_info
{
bool *unsafeColumns; /* which output columns are unsafe to use */
bool unsafeVolatile; /* don't push down volatile quals */
bool unsafeLeaky; /* don't push down leaky quals */
} pushdown_safety_info;
@@ -119,20 +121,24 @@ static void check_output_expressions(Query *subquery,
static void compare_tlist_datatypes(List *tlist, List *colTypes,
pushdown_safety_info *safetyInfo);
static bool targetIsInAllPartitionLists(TargetEntry *tle, Query *query);
static bool qual_is_pushdown_safe(Query *subquery, Index rti, Node *qual,
pushdown_safety_info *safetyInfo);
static void subquery_push_qual(Query *subquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels);
+static void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
/*
* make_one_rel
* Finds all possible access paths for executing a query, returning a
* single rel that represents the join of all base rels in the query.
*/
RelOptInfo *
make_one_rel(PlannerInfo *root, List *joinlist)
{
@@ -861,20 +867,48 @@ static void
set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte)
{
int parentRTindex = rti;
bool has_live_children;
double parent_rows;
double parent_size;
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ Oid *part_oids = NULL;
+ int nparts = 0;
+
+ /*
+ * For a partitioned relation, we will save the child RelOptInfos in parent
+ * RelOptInfo in the same the order as corresponding bounds/lists are
+ * stored in the partition scheme.
+ */
+ if (rel->part_scheme)
+ {
+ RangeTblEntry *rte = root->simple_rte_array[rel->relid];
+
+ /*
+ * We need not lock the relation since it was already locked, either by
+ * the rewriter or when expand_inherited_rtentry() added it to the
+ * query's rangetable.
+ */
+ Relation relation = heap_open(rte->relid, NoLock);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+
+ part_oids = PartitionDescGetPartOids(part_desc);
+ nparts = part_desc->nparts;
+
+ Assert(part_oids && nparts > 0);
+
+ rel->part_rels = (RelOptInfo **)palloc0(sizeof(RelOptInfo *) * nparts);
+ heap_close(relation, NoLock);
+ }
/*
* Initialize to compute size estimates for whole append relation.
*
* We handle width estimates by weighting the widths of different child
* rels proportionally to their number of rows. This is sensible because
* the use of width estimates is mainly to compute the total relation
* "footprint" if we have to sort or hash it. To do this, we sum the
* total equivalent size (in "double" arithmetic) and then divide by the
* total rowcount estimate. This is done separately for the total rel
@@ -892,36 +926,80 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
List *childquals;
Node *childqual;
ListCell *parentvars;
ListCell *childvars;
+ int cnt_parts;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
/*
* The child rel's RelOptInfo was already created during
* add_base_rels_to_query.
*/
childrel = find_base_rel(root, childRTindex);
+
+ /*
+ * Save topmost parent's relid. If the parent itself is a child of some
+ * other relation, use parent's topmost parent relids.
+ */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
/*
+ * For a partitioned table, save the child RelOptInfo at its
+ * appropriate place in the parent RelOptInfo.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+
+ /*
+ * Copy/Modify targetlist. Partition-wise join technique may consider
+ * an OUTER join of another child relation with this child relation.
+ * In that case, even if this child is deemed empty, we will require
+ * the targetlist of this child to construct the nullable side. Hence
+ * set the targetlist before we prove that the child is empty and stop
+ * processing further.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ appinfo);
+
+ /*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
* baserestrictinfo quals are needed before we can check for
* constraint exclusion; so do that first and then check to see if we
* can disregard this child.
*
* As of 8.4, the child rel's targetlist might contain non-Var
* expressions, which means that substitution into the quals could
* produce opportunities for const-simplification, and perhaps even
* pseudoconstant quals. To deal with this, we strip the RestrictInfo
@@ -953,38 +1031,25 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
if (relation_excluded_by_constraints(root, childrel, childRTE))
{
/*
* This child need not be scanned, so we can omit it from the
* appendrel.
*/
set_dummy_rel_pathlist(childrel);
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying join quals. */
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
appinfo);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo);
/*
* We have to make child entries in the EquivalenceClass data
* structures as well. This is needed either if the parent
* participates in some eclass joins (because we will want to consider
* inner-indexscan joins on the individual children) or if the parent
* has useful pathkeys (because we should try to build MergeAppend
* paths that produce those sort orderings).
*/
if (rel->has_eclass_joins || has_useful_pathkeys(root, rel))
@@ -1073,20 +1138,28 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
if (child_width <= 0)
child_width = get_typavgwidth(exprType(childvar),
exprTypmod(childvar));
Assert(child_width > 0);
parent_attrsizes[pndx] += child_width * childrel->rows;
}
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ Assert(rel->part_rels[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
* Save the finished size estimates.
*/
int i;
Assert(parent_rows > 0);
rel->rows = parent_rows;
rel->reltarget->width = rint(parent_size / parent_rows);
@@ -1115,41 +1188,32 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
/*
* set_append_rel_pathlist
* Build access paths for an "append relation"
*/
static void
set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte)
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
- * Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * Generate access paths for each member relation and remember the
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
/* Re-locate the child RTE and RelOptInfo */
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
childrel = root->simple_rel_array[childRTindex];
@@ -1170,20 +1234,46 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
/*
* If child is dummy, ignore it.
*/
if (IS_DUMMY_REL(childrel))
continue;
/*
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid = true;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
* the unparameterized Append path we are constructing for the parent.
* If not, there's no workable unparameterized path.
*/
if (childrel->cheapest_total_path->param_info == NULL)
subpaths = accumulate_append_subpath(subpaths,
childrel->cheapest_total_path);
else
@@ -2188,20 +2278,22 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
* join_search_one_level. After that, we're done creating paths for
* the joinrel, so run set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
rel = (RelOptInfo *) lfirst(lc);
+ generate_partition_wise_join_paths(root, rel);
+
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
#ifdef OPTIMIZER_DEBUG
debug_print_rel(root, rel);
#endif
}
@@ -2849,20 +2941,73 @@ remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel)
* OK, we don't need it. Replace the expression with a NULL constant.
* Preserve the exposed type of the expression, in case something
* looks at the rowtype of the subquery's result.
*/
tle->expr = (Expr *) makeNullConst(exprType(texpr),
exprTypmod(texpr),
exprCollation(texpr));
}
}
+/*
+ * generate_partition_wise_join_paths
+ * Create appends paths containing partition-wise join paths for given
+ * join relation.
+ */
+static void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *live_children = NIL;
+ int cnt_part;
+ int nparts = PartitionSchemeGetNumParts(rel->part_scheme);
+
+ /* Handle only join relations. */
+ if (rel->reloptkind != RELOPT_JOINREL &&
+ rel->reloptkind != RELOPT_OTHER_JOINREL)
+ return;
+
+ /* If the relation is not partitioned, nothing to do. */
+ if (!rel->part_scheme || !rel->part_rels)
+ return;
+
+ for (cnt_part = 0; cnt_part < nparts; cnt_part++)
+ {
+ RelOptInfo *child_rel = rel->part_rels[cnt_part];
+
+ /* Ignore dummy child. */
+ if (!IS_DUMMY_REL(child_rel))
+ {
+ /* Recursively collect the paths from child joinrel. */
+ generate_partition_wise_join_paths(root, child_rel);
+
+ /* Find the cheapest of the paths for this rel. */
+ set_cheapest(child_rel);
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ live_children = lappend(live_children, child_rel);
+ }
+ }
+
+ /*
+ * Create append paths by collecting sub paths from live children. Even if
+ * there are no live children, we should create an append path with no
+ * subpaths i.e. a dummy access path.
+ */
+ add_paths_to_append_rel(root, rel, live_children);
+
+ if (live_children)
+ pfree(live_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
*****************************************************************************/
#ifdef OPTIMIZER_DEBUG
static void
print_relids(PlannerInfo *root, Relids relids)
{
int x;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 2a49639..a23da1c 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -119,20 +119,21 @@ bool enable_seqscan = true;
bool enable_indexscan = true;
bool enable_indexonlyscan = true;
bool enable_bitmapscan = true;
bool enable_tidscan = true;
bool enable_sort = true;
bool enable_hashagg = true;
bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
typedef struct
{
PlannerInfo *root;
QualCost total;
} cost_qual_eval_context;
static List *extract_nonindex_conditions(List *qual_clauses, List *indexquals);
static MergeScanSelCache *cached_scansel(PlannerInfo *root,
RestrictInfo *rinfo,
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index 0e50ad5..73026a3 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2359,20 +2359,22 @@ eclass_useful_for_merging(PlannerInfo *root,
/*
* Note we don't test ec_broken; if we did, we'd need a separate code path
* to look through ec_sources. Checking the members anyway is OK as a
* possibly-overoptimistic heuristic.
*/
/* If specified rel is a child, we must consider the topmost parent rel */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->top_parent_relids;
else
relids = rel->relids;
/* If rel already includes all members of eclass, no point in searching */
if (bms_is_subset(eclass->ec_relids, relids))
return false;
/* To join, we need a member not in the given rel */
foreach(lc, eclass->ec_members)
{
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index cc7384f..db0e469 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -18,23 +18,29 @@
#include "executor/executor.h"
#include "foreign/fdwapi.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void match_unsorted_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void consider_parallel_nestloop(PlannerInfo *root,
RelOptInfo *joinrel,
RelOptInfo *outerrel,
RelOptInfo *innerrel,
@@ -125,38 +131,51 @@ add_paths_to_joinrel(PlannerInfo *root,
* directly to the parameter source rel instead of joining to the other
* input rel. (But see allow_star_schema_join().) This restriction
* reduces the number of parameterized paths we have to deal with at
* higher join levels, without compromising the quality of the resulting
* plan. We express the restriction as a Relids set that must overlap the
* parameterization of any proposed join path.
*/
foreach(lc, root->join_info_list)
{
SpecialJoinInfo *sjinfo = (SpecialJoinInfo *) lfirst(lc);
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between partitions, even if there is a SpecialJoinInfo node for the
+ * join between the topmost parents. Hence while calculating Relids set
+ * representing the restriction, consider relids of topmost parent of
+ * partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
/*
* SJ is relevant to this join if we have some part of its RHS
* (possibly not all of it), and haven't yet joined to its LHS. (This
* test is pretty simplistic, but should be sufficient considering the
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_righthand))
+ bms_overlap(joinrelids, sjinfo->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_lefthand));
}
/*
* However, when a LATERAL subquery is involved, there will simply not be
* any paths for the joinrel that aren't parameterized by whatever the
* subquery is parameterized by, unless its parameterization is resolved
* within the joinrel. So we might as well allow additional dependencies
@@ -272,20 +291,35 @@ try_nestloop_path(PlannerInfo *root,
Path *outer_path,
Path *inner_path,
List *pathkeys,
JoinType jointype,
JoinPathExtraData *extra)
{
Relids required_outer;
JoinCostWorkspace workspace;
/*
+ * An inner path parameterized by the parent relation of outer
+ * relation needs to be reparameterized by the outer relation to be used
+ * for parameterized nested loop join.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_for_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
* doesn't like the look of it, which could only happen if the nestloop is
* still parameterized.
*/
required_outer = calc_nestloop_required_outer(outer_path,
inner_path);
if (required_outer &&
((!bms_overlap(required_outer, extra->param_source_rels) &&
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..4c51dd2 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -7,38 +7,56 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* src/backend/optimizer/path/joinrels.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
+#include "catalog/partition.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
static void make_rels_by_clause_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static void make_rels_by_clauseless_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static SpecialJoinInfo * build_partition_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1,
+ List *append_rel_infos2);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
/*
* join_search_one_level
* Consider ways to produce join relations containing exactly 'level'
* jointree items. (This is one step of the dynamic-programming method
* embodied in standard_join_search.) Join rel nodes for each feasible
* combination of lower-level rels are created and returned in a list.
* Implementation paths are created for each such joinrel, too.
*
@@ -717,20 +735,44 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
/*
* If we've already proven this join is empty, we needn't consider any
* more paths for it.
*/
if (is_dummy_rel(joinrel))
{
bms_free(joinrelids);
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Create paths to join given input relation and add those to the given
+ * joinrel. The SpecialJoinInfo provides details about the join and the
+ * restrictlist contains the join clauses and the other clauses applicable
+ * for given pair of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
* is provably empty too; in which case throw away any previously computed
* paths and mark the join as dummy. (We do it this way since it's
* conceivable that dummy-ness of a multi-element join might only be
* noticeable for certain construction paths.)
*
* Also, a provably constant-false join restriction typically means that
* we can skip evaluating one or both sides of the join. We do this by
@@ -861,27 +903,22 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
mark_dummy_rel(rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
break;
default:
/* other values not expected here */
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
-
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
* a join-order restriction arising from special or lateral joins.
*
* In practice this is always used with have_relevant_joinclause(), and so
* could be merged with that function, but it seems clearer to separate the
* two concerns. We need this test because there are degenerate cases where
* a clauseless join must be performed to satisfy join-order restrictions.
* Also, if one rel has a lateral reference to the other, or both are needed
@@ -1242,10 +1279,314 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
/* constant NULL is as good as constant FALSE for our purposes */
if (con->constisnull)
return true;
if (!DatumGetBool(con->constvalue))
return true;
}
}
return false;
}
+
+/*
+ * If the join between the given two relations can be executed as
+ * partition-wise join create the join relations for partition-wise join,
+ * create paths for those and then create append paths to combine
+ * partition-wise join results.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ StringInfo rel1_desc;
+ StringInfo rel2_desc;
+ PartitionScheme part_scheme;
+
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, the given partition scheme can not be used for
+ * partition-wise join between these two relations.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = PartitionSchemeGetNumParts(part_scheme);
+ rel1_desc = makeStringInfo();
+ rel2_desc = makeStringInfo();
+
+ /* TODO: remove this notice when finalising the patch. */
+ outBitmapset(rel1_desc, rel1->relids);
+ outBitmapset(rel2_desc, rel2->relids);
+ elog(NOTICE, "join between relations %s and %s is considered for partition-wise join.",
+ rel1_desc->data, rel2_desc->data);
+
+ /*
+ * We allocate the array for child RelOptInfos till we find at least one
+ * join order which can use partition-wise join technique. If no join order
+ * can use partition-wise join technique, there are no child relations.
+ */
+
+ if (!joinrel->part_rels)
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create join relations for the partition relations, if they do not exist
+ * already. Add paths to those for the given pair of joining relations.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_joinrel;
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ List *join_aris;
+ List *ari1;
+ List *ari2;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ /*
+ * Gather the AppendRelInfos for base partition relations
+ * partiticipating in the given partition relations. We need them
+ * construct partition-wise join relation, special join info and
+ * restriction list by substituting the Var and relids from parent to
+ * child.
+ */
+ ari1 = find_appendrelinfos_by_relids(root, child_rel1->relids);
+ ari2 = find_appendrelinfos_by_relids(root, child_rel2->relids);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_partition_join_sjinfo(root, parent_sjinfo, ari1, ari2);
+
+ /* Construct the parent-child relid map for the join relation. */
+ join_aris = list_concat(ari1, ari2);
+
+ /*
+ * Construct restrictions applicable to the partition-wise join from
+ * those applicable to the join between the parents.
+ */
+ child_restrictlist = (List *) adjust_partitionrel_attrs(root,
+ (Node *)parent_restrictlist,
+ join_aris);
+
+ child_joinrel = joinrel->part_rels[cnt_parts];
+
+ /* Construct the join relation for given partition of the join. */
+ if (!child_joinrel)
+ {
+ child_joinrel = build_partition_join_rel(root, child_rel1,
+ child_rel2, joinrel,
+ child_sjinfo,
+ child_restrictlist,
+ join_aris);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ }
+
+ /*
+ * If we've already proven that this join is empty, we needn't consider
+ * any more paths for it.
+ */
+ if (is_dummy_rel(child_joinrel))
+ continue;
+
+ populate_joinrel_with_paths(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the partition themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+ }
+}
+
+/*
+ * Construct the SpecialJoinInfo for the partition-wise join using parents'
+ * special join info. Also, instead of
+ * constructing an sjinfo everytime, we should probably save it in
+ * root->join_info_list and search within it like join_is_legal?
+ */
+static SpecialJoinInfo *
+build_partition_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1, List *append_rel_infos2)
+{
+ SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo);
+ sjinfo->min_lefthand = adjust_partition_relids(sjinfo->min_lefthand,
+ append_rel_infos1);
+ sjinfo->min_righthand = adjust_partition_relids(sjinfo->min_righthand,
+ append_rel_infos2);
+ sjinfo->syn_lefthand = adjust_partition_relids(sjinfo->syn_lefthand,
+ append_rel_infos1);
+ sjinfo->syn_righthand = adjust_partition_relids(sjinfo->syn_righthand,
+ append_rel_infos2);
+
+ /* Replace the Var nodes of parent with those of children in expressions. */
+ sjinfo->semi_rhs_exprs = (List *) adjust_partitionrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ append_rel_infos2);
+ return sjinfo;
+}
+
+/*
+ * Substitute oldrelids with newrelids in the given Relids set. It recycles the
+ * given relids input.
+ */
+Relids
+adjust_partition_relids(Relids relids, List *append_rel_infos)
+{
+ ListCell *lc;
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *ari = lfirst(lc);
+
+ /* Remove old, add new */
+ if (bms_is_member(ari->parent_relid, relids))
+ {
+ relids = bms_del_member(relids, ari->parent_relid);
+ relids = bms_add_member(relids, ari->child_relid);
+ }
+ }
+ return relids;
+}
+
+/*
+ * Returns true if the given relations have equi-join clauses on all the
+ * corresponding partition keys.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks = PartitionSchemeGetNumKeys(part_scheme);
+ bool *pk_has_clause;
+
+ Assert(rel1->part_scheme == rel2->part_scheme);
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip non-equi-join clauses. */
+ if (!rinfo->can_join ||
+ rinfo->hashjoinoperator == InvalidOid ||
+ !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+ /*
+ * If clause of form rel1_expr op rel2_expr OR rel2_expr op rel1_expr,
+ * match the operands to the relations. Otherwise, the clause is
+ * not an equi-join between partition keys of joining relations.
+ */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ if (ipk1 == ipk2)
+ pk_has_clause[ipk1] = true;
+ }
+
+ /*
+ * If every pair of partition key from either of the joining relation has
+ * at least one equi-join clause associated with it, we have an equi-join
+ * between all corresponding partition keys.
+ */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * match_expr_to_partition_keys
+ *
+ * Find the partition key which is same as the given expression. If found,
+ * return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks = PartitionSchemeGetNumKeys(rel->part_scheme);
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() will have simplied if more
+ * than one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/path/pathkeys.c b/src/backend/optimizer/path/pathkeys.c
index 4436ac1..c8870c8 100644
--- a/src/backend/optimizer/path/pathkeys.c
+++ b/src/backend/optimizer/path/pathkeys.c
@@ -1081,26 +1081,38 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
RelOptInfo *joinrel)
{
List *pathkeys = NIL;
int nClauses = list_length(mergeclauses);
EquivalenceClass **ecs;
int *scores;
int necs;
ListCell *lc;
int j;
+ Relids relids;
/* Might have no mergeclauses */
if (nClauses == 0)
return NIL;
/*
+ * Code below scores equivalence classes by how many equivalence members
+ * can produce join clauses for this join relation. Equivalence members
+ * which do not cover the parents of a partition-wise join relation, can
+ * produce join clauses for partition-wise join relation.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
+ /*
* Make arrays of the ECs used by the mergeclauses (dropping any
* duplicates) and their "popularity" scores.
*/
ecs = (EquivalenceClass **) palloc(nClauses * sizeof(EquivalenceClass *));
scores = (int *) palloc(nClauses * sizeof(int));
necs = 0;
foreach(lc, mergeclauses)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
@@ -1126,21 +1138,21 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
continue;
/* compute score */
score = 0;
foreach(lc2, oeclass->ec_members)
{
EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
/* Potential future join partner? */
if (!em->em_is_const && !em->em_is_child &&
- !bms_overlap(em->em_relids, joinrel->relids))
+ !bms_overlap(em->em_relids, relids))
score++;
}
ecs[necs] = oeclass;
scores[necs] = score;
necs++;
}
/*
* Find out if we have all the ECs mentioned in query_pathkeys; if so we
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 32f4031..b221e2c 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -235,21 +235,22 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
const AttrNumber *reqColIdx,
bool adjust_tlist_in_place,
int *p_numsortkeys,
AttrNumber **p_sortColIdx,
Oid **p_sortOperators,
Oid **p_collations,
bool **p_nullsFirst);
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
static Material *make_material(Plan *lefttree);
static WindowAgg *make_windowagg(List *tlist, Index winref,
int partNumCols, AttrNumber *partColIdx, Oid *partOperators,
int ordNumCols, AttrNumber *ordColIdx, Oid *ordOperators,
int frameOptions, Node *startOffset, Node *endOffset,
Plan *lefttree);
static Group *make_group(List *tlist, List *qual, int numGroupCols,
@@ -1507,21 +1508,21 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
Plan *subplan;
/*
* We don't want any excess columns in the sorted tuples, so request a
* smaller tlist. Otherwise, since Sort doesn't project, tlist
* requirements pass through.
*/
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
return plan;
}
/*
* create_group_plan
*
* Create a Group plan for 'best_path' and (recursively) plans
@@ -3517,31 +3518,33 @@ create_mergejoin_plan(PlannerInfo *root,
List *innerpathkeys;
int nClauses;
Oid *mergefamilies;
Oid *mergecollations;
int *mergestrategies;
bool *mergenullsfirst;
int i;
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
* inputs. However, if we're intending to sort an input's result, it's
* best to request a small tlist so we aren't sorting more data than
* necessary.
*/
- outer_plan = create_plan_recurse(root, best_path->jpath.outerjoinpath,
+ outer_plan = create_plan_recurse(root, outer_path,
(best_path->outersortkeys != NIL) ? CP_SMALL_TLIST : 0);
- inner_plan = create_plan_recurse(root, best_path->jpath.innerjoinpath,
+ inner_plan = create_plan_recurse(root, inner_path,
(best_path->innersortkeys != NIL) ? CP_SMALL_TLIST : 0);
/* Sort join qual clauses into best execution order */
/* NB: do NOT reorder the mergeclauses */
joinclauses = order_qual_clauses(root, best_path->jpath.joinrestrictinfo);
/* Get the join qual clauses (in plain expression form) */
/* Any pseudoconstant clauses are ignored here */
if (IS_OUTER_JOIN(best_path->jpath.jointype))
{
@@ -3573,48 +3576,52 @@ create_mergejoin_plan(PlannerInfo *root,
otherclauses = (List *)
replace_nestloop_params(root, (Node *) otherclauses);
}
/*
* Rearrange mergeclauses, if needed, so that the outer variable is always
* on the left; mark the mergeclause restrictinfos with correct
* outer_is_left status.
*/
mergeclauses = get_switched_clauses(best_path->path_mergeclauses,
- best_path->jpath.outerjoinpath->parent->relids);
+ outer_path->parent->relids);
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
outerpathkeys = best_path->outersortkeys;
}
else
- outerpathkeys = best_path->jpath.outerjoinpath->pathkeys;
+ outerpathkeys = outer_path->pathkeys;
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
innerpathkeys = best_path->innersortkeys;
}
else
- innerpathkeys = best_path->jpath.innerjoinpath->pathkeys;
+ innerpathkeys = inner_path->pathkeys;
/*
* If specified, add a materialize node to shield the inner plan from the
* need to handle mark/restore.
*/
if (best_path->materialize_inner)
{
Plan *matplan = (Plan *) make_material(inner_plan);
/*
@@ -5330,25 +5337,25 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any
* further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
exprvars = pull_var_clause((Node *) sortexpr,
PVC_INCLUDE_AGGREGATES |
PVC_INCLUDE_WINDOWFUNCS |
PVC_INCLUDE_PLACEHOLDERS);
foreach(k, exprvars)
{
if (!tlist_member_ignore_relabel(lfirst(k), tlist))
@@ -5445,57 +5452,58 @@ find_ec_member_for_tle(EquivalenceClass *ec,
Expr *emexpr;
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
emexpr = em->em_expr;
while (emexpr && IsA(emexpr, RelabelType))
emexpr = ((RelabelType *) emexpr)->arg;
if (equal(emexpr, tlexpr))
return em;
}
return NULL;
}
/*
* make_sort_from_pathkeys
* Create sort plan to sort according to given pathkeys
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
Oid *sortOperators;
Oid *collations;
bool *nullsFirst;
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
&sortColIdx,
&sortOperators,
&collations,
&nullsFirst);
/* Now build the Sort node */
return make_sort(lefttree, numsortkeys,
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 592214b..2e327a8 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -1873,20 +1873,71 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
appinfo);
}
result = (Node *) newnode;
}
else
result = adjust_appendrel_attrs_mutator(node, &context);
return result;
}
+/*
+ * find_appendrelinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appendrelinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *ari_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *ari = lfirst(lc);
+
+ if (bms_is_member(ari->child_relid, relids))
+ ari_list = lappend(ari_list, ari);
+ }
+
+ Assert(list_length(ari_list) == bms_num_members(relids));
+ return ari_list;
+}
+
+/*
+ * adjust_partitionrel_attrs
+ * Replace the Var nodes in given node with the corresponding Var nodes
+ * of the child. Given list of AppendRelInfo nodes holds the mapping
+ * between parent and child Var nodes.
+ *
+ * While doing so, we need to make sure to translate non-expression information
+ * in nodes like RestrictInfo.
+ */
+Node *
+adjust_partitionrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos)
+{
+ ListCell *lc;
+
+ /*
+ * TODO: Instead of copying and mutating the trees one child relation at a
+ * time, we should be able to do this en-masse for all the partitions
+ * involved.
+ */
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *append_rel_info = lfirst(lc);
+ node = adjust_appendrel_attrs(root, node, append_rel_info);
+ }
+
+ return node;
+}
+
static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
AppendRelInfo *appinfo = context->appinfo;
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index abb7507..ba64329 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -16,21 +16,23 @@
#include <math.h>
#include "miscadmin.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
#include "utils/selfuncs.h"
typedef enum
{
COSTS_EQUAL, /* path costs are fuzzily equal */
COSTS_BETTER1, /* first path is cheaper than second */
@@ -3202,10 +3204,160 @@ reparameterize_path(PlannerInfo *root, Path *path,
rel,
spath->subpath,
spath->path.pathkeys,
required_outer);
}
default:
break;
}
return NULL;
}
+
+/*
+ * reparameterize_path_for_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ */
+Path *
+reparameterize_path_for_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+
+ /*
+ * If the path is not parameterized by parent of the given relation, it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appendrelinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = adjust_partition_relids(bms_copy(old_ppi->ppi_req_outer),
+ child_aris);
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = (List *) adjust_partitionrel_attrs(root,
+ (Node *) old_ppi->ppi_clauses,
+ child_aris);
+
+ /* Adjust the path target. */
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_partitionrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ new_path->param_info = new_ppi;
+
+ /*
+ * Change parameterization of sub paths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_for_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_for_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = (List *) adjust_partitionrel_attrs(root,
+ (Node *) jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_for_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexquals = (List *) adjust_partitionrel_attrs(root,
+ (Node *) ipath->indexquals,
+ child_aris);
+ ipath->indexquals = (List *) adjust_partitionrel_attrs(root,
+ (Node *) ipath->indexorderbys,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 6ef45d5..6512227 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -404,20 +404,35 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
else
{
rel->serverid = InvalidOid;
rel->fdwroutine = NULL;
}
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation);
+ /*
+ * Lookup partition scheme for the given relation. Only parent relations
+ * can be partitioned.
+ */
+ if (inhparent)
+ rel->part_scheme = find_partition_scheme(root, relation);
+ else
+ rel->part_scheme = NULL;
+
+ if (rel->part_scheme)
+ rel->partexprs = build_baserel_partition_keys(root, relation,
+ rel->relid);
+ else
+ rel->partexprs = NULL;
+
heap_close(relation, NoLock);
/*
* Allow a plugin to editorialize on the info we obtained from the
* catalogs. Actions might include altering the assumed relation size,
* removing an index, or adding a hypothetical index to the indexlist.
*/
if (get_relation_info_hook)
(*get_relation_info_hook) (root, relationObjectId, inhparent, rel);
}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index deef560..d1f6c04 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -8,29 +8,35 @@
*
*
* IDENTIFICATION
* src/backend/optimizer/util/relnode.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
+#include "catalog/partition.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
+#include "nodes/makefuncs.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
{
Relids join_relids; /* hash key --- MUST BE FIRST */
RelOptInfo *join_rel;
} JoinHashEntry;
static void build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel);
@@ -40,20 +46,22 @@ static List *build_joinrel_restrictlist(PlannerInfo *root,
RelOptInfo *inner_rel);
static void build_joinrel_joinlist(RelOptInfo *joinrel,
RelOptInfo *outer_rel,
RelOptInfo *inner_rel);
static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_restrictlist);
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
/*
* setup_simple_rel_arrays
* Prepare the arrays we use for quickly accessing base relations.
*/
void
setup_simple_rel_arrays(PlannerInfo *root)
{
Index rti;
@@ -130,20 +138,24 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
rel->serverid = InvalidOid;
rel->userid = rte->checkAsUser;
rel->useridiscurrent = false;
rel->fdwroutine = NULL;
rel->fdw_private = NULL;
rel->baserestrictinfo = NIL;
rel->baserestrictcost.startup = 0;
rel->baserestrictcost.per_tuple = 0;
rel->joininfo = NIL;
rel->has_eclass_joins = false;
+ rel->part_scheme = NULL;
+ rel->partexprs = NULL;
+ rel->top_parent_relids = NULL;
+ rel->part_rels = NULL;
/* Check type of rtable entry */
switch (rte->rtekind)
{
case RTE_RELATION:
/* Table --- retrieve statistics from the system catalogs */
get_relation_info(root, rte->relid, rte->inh, rel);
break;
case RTE_SUBQUERY:
case RTE_FUNCTION:
@@ -307,20 +319,70 @@ find_join_rel(PlannerInfo *root, Relids relids)
if (bms_equal(rel->relids, relids))
return rel;
}
}
return NULL;
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
*
* 'joinrelids' is the Relids set that uniquely identifies the join
* 'outer_rel' and 'inner_rel' are relation nodes for the relations to be
* joined
* 'sjinfo': join context info
* 'restrictlist_ptr': result variable. If not NULL, *restrictlist_ptr
* receives the list of RestrictInfo nodes that apply to this
@@ -356,21 +418,25 @@ build_join_rel(PlannerInfo *root,
joinrel,
outer_rel,
inner_rel);
return joinrel;
}
/*
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
+
+ Assert(!IS_OTHER_REL(outer_rel->reloptkind) &&
+ !IS_OTHER_REL(inner_rel->reloptkind));
joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
joinrel->consider_startup = (root->tuple_fraction > 0);
joinrel->consider_param_startup = false;
joinrel->consider_parallel = false;
joinrel->reltarget = create_empty_pathtarget();
joinrel->pathlist = NIL;
joinrel->ppilist = NIL;
joinrel->partial_pathlist = NIL;
@@ -402,61 +468,27 @@ build_join_rel(PlannerInfo *root,
joinrel->serverid = InvalidOid;
joinrel->userid = InvalidOid;
joinrel->useridiscurrent = false;
joinrel->fdwroutine = NULL;
joinrel->fdw_private = NULL;
joinrel->baserestrictinfo = NIL;
joinrel->baserestrictcost.startup = 0;
joinrel->baserestrictcost.per_tuple = 0;
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Computer information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
* this join (ie, are needed for higher joinclauses or final output).
*
* NOTE: the tlist order for a join rel will depend on which pair of outer
* and inner rels we first try to build it from. But the contents should
* be the same regardless.
*/
build_joinrel_tlist(root, joinrel, outer_rel);
@@ -468,20 +500,24 @@ build_join_rel(PlannerInfo *root,
* sets of any PlaceHolderVars computed here to direct_lateral_relids, so
* now we can finish computing that. This is much like the computation of
* the transitively-closed lateral_relids in min_join_parameterization,
* except that here we *do* have to consider the added PHVs.
*/
joinrel->direct_lateral_relids =
bms_del_members(joinrel->direct_lateral_relids, joinrel->relids);
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
* for set_joinrel_size_estimates().)
*/
restrictlist = build_joinrel_restrictlist(root, joinrel,
outer_rel, inner_rel);
if (restrictlist_ptr)
*restrictlist_ptr = restrictlist;
build_joinrel_joinlist(joinrel, outer_rel, inner_rel);
@@ -510,57 +546,153 @@ build_join_rel(PlannerInfo *root,
* assume this doesn't matter, because we should hit all the same baserels
* and joinclauses while building up to this joinrel no matter which we
* take; therefore, we should make the same decision here however we get
* here.
*/
if (inner_rel->consider_parallel && outer_rel->consider_parallel &&
is_parallel_safe(root, (Node *) restrictlist) &&
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the query's PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
* to the appropriate sublist. Note: you might think the Assert on number
* of members should be for equality, but some of the level 1 rels might
* have been joinrels already, so we can only assert <=.
*/
if (root->join_rel_level)
{
Assert(root->join_cur_level > 0);
Assert(root->join_cur_level <= bms_num_members(joinrel->relids));
root->join_rel_level[root->join_cur_level] =
lappend(root->join_rel_level[root->join_cur_level], joinrel);
}
return joinrel;
}
+RelOptInfo *
+build_partition_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist,
+ List *join_aris)
+{
+ List *tmp_exprs;
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel->reloptkind) &&
+ IS_OTHER_REL(inner_rel->reloptkind));
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Computer information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /*
+ * Produce partition-wise joinrel's targetlist by translating the parent
+ * joinrel's targetlist. This will also include the required placeholder
+ * Vars.
+ */
+ joinrel->reltarget = copy_pathtarget(parent_joinrel->reltarget);
+ tmp_exprs = joinrel->reltarget->exprs;
+ joinrel->reltarget->exprs = (List *) adjust_partitionrel_attrs(root, (Node *) tmp_exprs,
+ join_aris);
+
+ /*
+ * Lateral relids directly referred in this relation will be same as that
+ * of the parent relation.
+ */
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ joinrel->joininfo = (List *) adjust_partitionrel_attrs(root,
+ (Node *) parent_joinrel->joininfo,
+ join_aris);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, sjinfo->jointype);
+
+ /*
+ * Set estimates of the joinrel's size.
+ */
+ set_joinrel_size_estimates(root, joinrel, outer_rel, inner_rel, sjinfo,
+ restrictlist);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
/*
* min_join_parameterization
*
* Determine the minimum possible parameterization of a joinrel, that is, the
* set of other rels it contains LATERAL references to. We save this value in
* the join's RelOptInfo. This function is split out of build_join_rel()
* because join_is_legal() needs the value to check a prospective join.
*/
Relids
min_join_parameterization(PlannerInfo *root,
@@ -1313,10 +1445,35 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
ppi->ppi_req_outer = required_outer;
ppi->ppi_rows = 0;
ppi->ppi_clauses = NIL;
appendrel->ppilist = lappend(appendrel->ppilist, ppi);
return ppi;
}
+
+/*
+ * Adds given join relation to the joinrel list and also to the hashtable if
+ * there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 56943f2..16b2eac 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3405,21 +3405,23 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
else
{
/* not time to process varinfo2 yet */
newvarinfos = lcons(varinfo2, newvarinfos);
}
}
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
if (rel->tuples > 0)
{
/*
* Clamp to size of rel, or size of rel / 10 if multiple Vars. The
* fudge factor is because the Vars are probably correlated but we
* don't know by how much. We should never clamp to less than the
* largest ndistinct value for any of the Vars, though, since
* there will surely be at least that many groups.
*/
double clamp = rel->tuples;
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index c5178f7..3412eae 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -870,20 +870,29 @@ static struct config_bool ConfigureNamesBool[] =
},
{
{"enable_hashjoin", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of hash join plans."),
NULL
},
&enable_hashjoin,
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
gettext_noop("Enables genetic query optimization."),
gettext_noop("This algorithm attempts to do planning without "
"exhaustive searching.")
},
&enable_geqo,
true,
NULL, NULL, NULL
diff --git a/src/include/catalog/partition.h b/src/include/catalog/partition.h
index 14fd29e..9d552b3 100644
--- a/src/include/catalog/partition.h
+++ b/src/include/catalog/partition.h
@@ -9,37 +9,39 @@
* src/include/utils/partition.h
*
*-------------------------------------------------------------------------
*/
#ifndef PARTITION_H
#define PARTITION_H
#include "fmgr.h"
#include "executor/tuptable.h"
#include "nodes/execnodes.h"
+#include "nodes/relation.h"
#include "parser/parse_node.h"
#include "utils/relcache.h"
typedef struct PartitionKeyData *PartitionKey;
/*
* Information about partitions of a partitioned table.
*/
typedef struct PartitionInfoData *PartitionInfo;
typedef struct PartitionDescData
{
int nparts; /* Number of partitions */
PartitionInfo *parts; /* Array of PartitionInfoData pointers */
} PartitionDescData;
typedef struct PartitionDescData *PartitionDesc;
typedef struct PartitionTreeNodeData *PartitionTreeNode;
+typedef struct PartitionSchemeData *PartitionScheme;
/* relcache support for partition key information */
extern void RelationBuildPartitionKey(Relation relation);
/* Partition key inquiry functions */
extern int get_partition_key_strategy(PartitionKey key);
extern int get_partition_key_natts(PartitionKey key);
extern List *get_partition_key_exprs(PartitionKey key);
/* Partition key inquiry functions - for a given column */
@@ -62,11 +64,21 @@ extern List *get_check_qual_from_partbound(Relation rel, Relation parent,
extern List *RelationGetPartitionCheckQual(Relation rel);
/* For tuple routing */
extern PartitionTreeNode RelationGetPartitionTreeNode(Relation rel);
extern List *get_leaf_partition_oids_v2(PartitionTreeNode ptnode);
extern int get_partition_for_tuple(PartitionTreeNode ptnode,
TupleTableSlot *slot,
EState *estate,
Oid *failed_at);
+extern List **build_baserel_partition_keys(PlannerInfo *root,
+ Relation relation, Index varno);
+extern PartitionScheme find_partition_scheme(PlannerInfo *root, Relation rel);
+extern int PartitionSchemeGetNumParts(PartitionScheme part_scheme);
+extern int PartitionSchemeGetNumKeys(PartitionScheme part_scheme);
+extern Oid *PartitionDescGetPartOids(PartitionDesc part_desc);
+extern void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
+
#endif /* PARTITION_H */
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 2709cc7..29b419a 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -256,20 +256,23 @@ typedef struct PlannerInfo
List *query_pathkeys; /* desired pathkeys for query_planner() */
List *group_pathkeys; /* groupClause pathkeys, if any */
List *window_pathkeys; /* pathkeys of bottom window, if any */
List *distinct_pathkeys; /* distinctClause pathkeys, if any */
List *sort_pathkeys; /* sortClause pathkeys, if any */
List *initial_rels; /* RelOptInfos we are now trying to join */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
/* Use fetch_upper_rel() to get any particular upper rel */
List *upper_rels[UPPERREL_FINAL + 1]; /* upper-rel RelOptInfos */
/* Result tlists chosen by grouping_planner for upper-stage processing */
struct PathTarget *upper_targets[UPPERREL_FINAL + 1];
/*
* grouping_planner passes back its final processed targetlist here, for
* use in relabeling the topmost tlist of the finished Plan.
*/
@@ -345,20 +348,26 @@ typedef struct PlannerInfo
* is present in the query join tree but the members are not. The member
* RTEs and otherrels are used to plan the scans of the individual tables or
* subqueries of the append set; then the parent baserel is given Append
* and/or MergeAppend paths comprising the best paths for the individual
* member rels. (See comments for AppendRelInfo for more information.)
*
* At one time we also made otherrels to represent join RTEs, for use in
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing pair-wise joins between partitions of
+ * partitioned tables. These relations are not added to join_rel_level lists
+ * as they are not joined directly by the dynamic programming algorithm.
+ * Adding these two join_rel_level list also means that top level list has more
+ * than one join relation, which is symantically incorrect.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
* fields always hold Paths showing ways to do that processing step.
*
* Lastly, there is a RelOptKind for "dead" relations, which are base rels
* that we have proven we don't need to join after all.
*
* Parts of this data structure are specific to various scan and join
* mechanisms. It didn't seem worth creating new node types for them.
@@ -464,24 +473,31 @@ typedef struct PlannerInfo
* We store baserestrictcost in the RelOptInfo (for base relations) because
* we know we will need it at least once (to price the sequential scan)
* and may need it multiple times to price index scans.
*----------
*/
typedef enum RelOptKind
{
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(reloptkind) \
+ ((reloptkind) == RELOPT_OTHER_MEMBER_REL || \
+ (reloptkind) == RELOPT_OTHER_JOINREL)
+
+typedef struct PartitionSchemeData *PartitionScheme;
+
typedef struct RelOptInfo
{
NodeTag type;
RelOptKind reloptkind;
/* all relations included in this RelOptInfo */
Relids relids; /* set of base relids (rangetable indexes) */
/* size estimates generated by planner */
@@ -535,20 +551,37 @@ typedef struct RelOptInfo
struct FdwRoutine *fdwroutine;
void *fdw_private;
/* used by various scans and joins: */
List *baserestrictinfo; /* RestrictInfo structures (if base
* rel) */
QualCost baserestrictcost; /* cost of evaluating the above */
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations, joins or base relations. NULL otherwise. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there can be as many elements
+ * as there are number of joining
+ * relations.
+ */
+
+ /* Set only for "other" base or join relations. */
+ Relids top_parent_relids;
} RelOptInfo;
/*
* IndexOptInfo
* Per-index information for planning/optimization
*
* indexkeys[], indexcollations[], opfamily[], and opcintype[]
* each have ncolumns entries.
*
* sortopfamily[], reverse_sort[], and nulls_first[] likewise have
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..1069726 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -59,20 +59,21 @@ extern bool enable_seqscan;
extern bool enable_indexscan;
extern bool enable_indexonlyscan;
extern bool enable_bitmapscan;
extern bool enable_tidscan;
extern bool enable_sort;
extern bool enable_hashagg;
extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
double index_pages, PlannerInfo *root);
extern void cost_seqscan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_samplescan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_index(IndexPath *path, PlannerInfo *root,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 71d9154..2ab31d3 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -222,20 +222,22 @@ extern ModifyTablePath *create_modifytable_path(PlannerInfo *root,
List *rowMarks, OnConflictExpr *onconflict,
int epqParam);
extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_for_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
*/
extern void setup_simple_rel_arrays(PlannerInfo *root);
extern RelOptInfo *build_simple_rel(PlannerInfo *root, int relid,
RelOptKind reloptkind);
extern RelOptInfo *find_base_rel(PlannerInfo *root, int relid);
extern RelOptInfo *find_join_rel(PlannerInfo *root, Relids relids);
extern RelOptInfo *build_join_rel(PlannerInfo *root,
@@ -260,12 +262,17 @@ extern ParamPathInfo *get_baserel_parampathinfo(PlannerInfo *root,
Relids required_outer);
extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
RelOptInfo *joinrel,
Path *outer_path,
Path *inner_path,
SpecialJoinInfo *sjinfo,
Relids required_outer,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_partition_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, SpecialJoinInfo *sjinfo,
+ List *restrictlist, List *join_aris);
+extern void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..a799428 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -212,11 +212,13 @@ extern List *make_inner_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
List *outer_pathkeys);
extern List *truncate_useless_pathkeys(PlannerInfo *root,
RelOptInfo *rel,
List *pathkeys);
extern bool has_useful_pathkeys(PlannerInfo *root, RelOptInfo *rel);
extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+extern Relids adjust_partition_relids(Relids relids, List *append_rel_infos);
+
#endif /* PATHS_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index fb35b68..7b149c3 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -21,20 +21,23 @@
/*
* prototypes for prepjointree.c
*/
extern void pull_up_sublinks(PlannerInfo *root);
extern void inline_set_returning_functions(PlannerInfo *root);
extern void pull_up_subqueries(PlannerInfo *root);
extern void flatten_simple_union_all(PlannerInfo *root);
extern void reduce_outer_joins(PlannerInfo *root);
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
+extern Node *adjust_partitionrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos);
+extern List *find_appendrelinfos_by_relids(PlannerInfo *root, Relids relids);
/*
* prototypes for prepqual.c
*/
extern Node *negate_clause(Node *node);
extern Expr *canonicalize_qual(Expr *qual);
/*
* prototypes for prepsecurity.c
*/
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..a90be5a
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,6884 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (((t1.a + t1.b) / 2) = ((t2.b + t2.a) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: (((t1_1.a + t1_1.b) / 2) = ((t2_1.b + t2_1.a) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: (((t1_2.a + t1_2.b) / 2) = ((t2_2.b + t2_2.a) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Sort Key: prt1_e_p1.a, prt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Hash Cond: (((prt1_e_p1.a + prt1_e_p1.b) / 2) = ((prt2_e_p1.b + prt2_e_p1.a) / 2))
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt1_e_p1.b
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ -> Seq Scan on public.prt2_e_p1
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ Filter: ((prt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt2_e_p2.b, prt2_e_p2.c
+ Hash Cond: (((prt1_e_p2.a + prt1_e_p2.b) / 2) = ((prt2_e_p2.b + prt2_e_p2.a) / 2))
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt1_e_p2.b
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ -> Seq Scan on public.prt2_e_p2
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ Filter: ((prt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt2_e_p3.b, prt2_e_p3.c
+ Hash Cond: (((prt1_e_p3.a + prt1_e_p3.b) / 2) = ((prt2_e_p3.b + prt2_e_p3.a) / 2))
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt1_e_p3.b
+ Filter: ((prt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ -> Seq Scan on public.prt2_e_p3
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ Filter: ((prt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t2.a, t2.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t2_1.a, t2_1.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t2_2.a, t2_2.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 18) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 22) and (b 9) is considered for partition-wise join.
+NOTICE: join between relations (b 26) and (b 13) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.b = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text) AND ((t1_1.b + t1_1.a) = (t2_1.a + t2_1.b)))
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.b = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text) AND ((t1_2.b + t1_2.a) = (t2_2.a + t2_2.b)))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
+ Hash Cond: ((t1_3.a = t2_3.b) AND (t1_3.b = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text) AND ((t1_3.b + t1_3.a) = (t2_3.a + t2_3.b)))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Hash
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: ((t2_3.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_4.b, t2_4.c, t1_4.a, t1_4.c
+ Hash Cond: ((t1_4.a = t2_4.b) AND (t1_4.b = t2_4.a) AND ((t1_4.c)::text = (t2_4.c)::text) AND ((t1_4.b + t1_4.a) = (t2_4.a + t2_4.b)))
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Hash
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: ((t2_4.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_5.b, t2_5.c, t1_5.a, t1_5.c
+ Hash Cond: ((t1_5.a = t2_5.b) AND (t1_5.b = t2_5.a) AND ((t1_5.c)::text = (t2_5.c)::text) AND ((t1_5.b + t1_5.a) = (t2_5.a + t2_5.b)))
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Hash
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: ((t2_5.b % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 18) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 22) and (b 9) is considered for partition-wise join.
+NOTICE: join between relations (b 26) and (b 13) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Sort Key: prt1_l_p1_p1.a, prt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt2_l_p1_p2.b, prt2_l_p1_p2.c
+ Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.c = t1.c) AND (t2.a = t1.a))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.c = t1_1.c) AND (t2_1.a = t1_1.a))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.c = t1_2.c) AND (t2_2.a = t1_2.a))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, avg(plt2_p1.b), plt2_p1.c
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, sum((25)), avg(plt2_p1.b), plt2_p1.c, avg((50))
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (25), (50)
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c, 25
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c, (50)
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c, 50
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, (25), (50)
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c, 25
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c, (50)
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c, 50
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, (25), (50)
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c, 25
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c, (50)
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c, 50
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (avg(t2.b)), t2.c
+ Sort Key: t1.c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, avg(t2.b), t2.c
+ Group Key: t1.c, t2.c
+ -> Result
+ Output: t1.c, t2.c, t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(20 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Left Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Left Join
+ Output: t1_1.a, t1_1.c, t2.b, t2.c
+ Hash Cond: (t1_1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(a)), c, (sum(t2.b)), t2.c
+ Sort Key: c, t2.c
+ -> HashAggregate
+ Output: sum(a), c, sum(t2.b), t2.c
+ Group Key: c, t2.c
+ -> Result
+ Output: c, t2.c, a, t2.b
+ -> Append
+ -> Hash Left Join
+ Output: t2.b, t2.c, a, c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1.a, t1.c
+ Hash Cond: (t1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (ltrim(t1.c, 'A'::text) = ltrim(t2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (ltrim(t1_1.c, 'A'::text) = ltrim(t2_1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (ltrim(t1_2.c, 'A'::text) = ltrim(t2_2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Sort Key: plt1_e_p1.a, plt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Hash Cond: ((plt1_e_p1.a = plt2_e_p1.b) AND (ltrim(plt1_e_p1.c, 'A'::text) = ltrim(plt2_e_p1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ -> Seq Scan on public.plt2_e_p1
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ Filter: ((plt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p2.a, plt1_e_p2.c, plt2_e_p2.b, plt2_e_p2.c
+ Hash Cond: ((plt1_e_p2.a = plt2_e_p2.b) AND (ltrim(plt1_e_p2.c, 'A'::text) = ltrim(plt2_e_p2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ -> Seq Scan on public.plt2_e_p2
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ Filter: ((plt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p3.a, plt1_e_p3.c, plt2_e_p3.b, plt2_e_p3.c
+ Hash Cond: ((plt1_e_p3.a = plt2_e_p3.b) AND (ltrim(plt1_e_p3.c, 'A'::text) = ltrim(plt2_e_p3.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ -> Seq Scan on public.plt2_e_p3
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ Filter: ((plt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((t3.a = t2.b) AND ((ltrim(t3.c, 'A'::text)) = t2.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (ltrim(t3.c, 'A'::text))
+ Sort Key: t3.a, (ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ltrim(t3.c, 'A'::text)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((t3_1.a = t2_1.b) AND ((ltrim(t3_1.c, 'A'::text)) = t2_1.c))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (ltrim(t3_1.c, 'A'::text))
+ Sort Key: t3_1.a, (ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ltrim(t3_1.c, 'A'::text)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((t3_2.a = t2_2.b) AND ((ltrim(t3_2.c, 'A'::text)) = t2_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (ltrim(t3_2.c, 'A'::text))
+ Sort Key: t3_2.a, (ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ltrim(t3_2.c, 'A'::text)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: ((ltrim(t1_6.c, 'A'::text)) = t1_3.c)
+ -> Sort
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Sort Key: (ltrim(t1_6.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Sort
+ Output: t1_3.c
+ Sort Key: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: ((ltrim(t1_7.c, 'A'::text)) = t1_4.c)
+ -> Sort
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Sort Key: (ltrim(t1_7.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Sort
+ Output: t1_4.c
+ Sort Key: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: ((ltrim(t1_8.c, 'A'::text)) = t1_5.c)
+ -> Sort
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Sort Key: (ltrim(t1_8.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+ -> Sort
+ Output: t1_5.c
+ Sort Key: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+(88 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (ltrim(t3.c, 'A'::text) = t2.c)
+ Join Filter: (t2.b = t3.a)
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iplt2_p1_c on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (ltrim(t3_1.c, 'A'::text) = t2_1.c)
+ Join Filter: (t2_1.b = t3_1.a)
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iplt2_p2_c on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: (ltrim(t3_2.c, 'A'::text) = t2_2.c)
+ Join Filter: (t2_2.b = t3_2.a)
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iplt2_p3_c on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Index Scan using iplt2_p1_c on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Index Scan using iplt1_p2_c on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Index Scan using iplt2_p2_c on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Index Scan using iplt2_p3_c on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Semi Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Index Only Scan using iplt2_p1_c on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Materialize
+ Output: t1_6.c
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t1_6
+ Output: t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Semi Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Index Only Scan using iplt2_p2_c on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Materialize
+ Output: t1_7.c
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t1_7
+ Output: t1_7.c
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Semi Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Index Only Scan using iplt2_p3_c on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Materialize
+ Output: t1_8.c
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t1_8
+ Output: t1_8.c
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- negative testcases
+--
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out
index f06cfa4..16e7f56 100644
--- a/src/test/regress/expected/rangefuncs.out
+++ b/src/test/regress/expected/rangefuncs.out
@@ -1,25 +1,26 @@
SELECT name, setting FROM pg_settings WHERE name LIKE 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
CREATE TABLE foo2(fooid int, f2 int);
INSERT INTO foo2 VALUES(1, 11);
INSERT INTO foo2 VALUES(2, 22);
INSERT INTO foo2 VALUES(1, 111);
CREATE FUNCTION foot(int) returns setof foo2 as 'SELECT * FROM foo2 WHERE fooid = $1 ORDER BY f2;' LANGUAGE SQL;
-- function with ORDINALITY
select * from foot(1) with ordinality as z(a,b,ord);
a | b | ord
---+-----+-----
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 1cb5dfc..d62841d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -93,21 +93,21 @@ test: alter_generic alter_operator misc psql async dbsize misc_functions
# rules cannot run concurrently with any test that creates a view
test: rules psql_crosstab amutils
# run by itself so it can run parallel workers
test: select_parallel
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
# so keep this parallel group to at most 19 tests
# ----------
test: plancache limit plpgsql copy2 temp domain rangefuncs prepare without_oid conversion truncate alter_table sequence polymorphism rowtypes returning largeobject with xml
# event triggers cannot run concurrently with any test that runs DDL
test: event_trigger
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 8958d8c..49a27b1 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -161,10 +161,11 @@ test: truncate
test: alter_table
test: sequence
test: polymorphism
test: rowtypes
test: returning
test: largeobject
test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..e4f05c7
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,769 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- negative testcases
+--
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
Hi,
I got a server crash with partition_wise_join, steps to reproduce given
below.
postgres=# set enable_partition_wise_join=true;
SET
postgres=# CREATE TABLE tbl (a int,c text) PARTITION BY LIST(a);
CREATE TABLE
postgres=# CREATE TABLE tbl_p1 PARTITION OF tbl FOR VALUES IN (1, 2);
CREATE TABLE
postgres=# CREATE TABLE tbl_p2 PARTITION OF tbl FOR VALUES IN (3, 4);
CREATE TABLE
postgres=# INSERT INTO tbl VALUES (1,'P1'),(2,'P1'),(3,'P2'),(4,'P2');
INSERT 0 4
postgres=# EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM tbl t1 INNER JOIN tbl
t2 ON (t1.a = t2.a) WHERE t1.c = 'P1' AND t1.c = 'P2';
NOTICE: join between relations (b 1) and (b 2) is considered for
partition-wise join.
server closed the connection unexpectedly
This probably means the server terminated abnormally
before or while processing the request.
The connection to the server was lost. Attempting reset: Failed.
!>
Thanks & Regards,
Rajkumar Raghuwanshi
QMG, EnterpriseDB Corporation
Import Notes
Resolved by subject fallback
Hi Rajkumar,
On Fri, Sep 16, 2016 at 6:00 PM, Rajkumar Raghuwanshi
<rajkumar.raghuwanshi@enterprisedb.com> wrote:
On Fri, Sep 9, 2016 at 3:17 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Hi All,
PFA the patch to support partition-wise joins for partitioned tables. The
patch
is based on the declarative parition support patches provided by Amit
Langote
on 26th August 2016.I have applied declarative partitioning patches posted by Amit Langote on 26
Aug 2016 and then partition-wise-join patch, getting below error while make
install.../../../../src/include/nodes/relation.h:706: error: redefinition of typedef
‘PartitionOptInfo’
../../../../src/include/nodes/relation.h:490: note: previous declaration of
‘PartitionOptInfo’ was here
make[4]: *** [gistbuild.o] Error 1
make[4]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src/backend/access/gist'
make[3]: *** [gist-recursive] Error 2
make[3]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src/backend/access'
make[2]: *** [access-recursive] Error 2
make[2]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src/backend'
make[1]: *** [all-backend-recurse] Error 2
make[1]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG/postgresql/src'
make: *** [all-src-recurse] Error 2PS : I am using - gcc (GCC) 4.4.7 20120313 (Red Hat 4.4.7-17)
Thanks for the report and the patch.
This is fixed by the patch posted with
/messages/by-id/CAFjFpRdRFWMc4zNjeJB6p1Ncpznc9DMdXfZJmVK5X_us5zeD9Q@mail.gmail.com.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Tue, Sep 20, 2016 at 4:26 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
PFA patch which takes care of some of the TODOs mentioned in my
previous mail. The patch is based on the set of patches supporting
declarative partitioning by Amit Langoted posted on 26th August.
I have applied declarative partitioning patches posted by Amit Langote on
26 Aug 2016 and then latest partition-wise-join patch, getting below error
while make install.
../../../../src/include/catalog/partition.h:37: error: redefinition of
typedef ‘PartitionScheme’
../../../../src/include/nodes/relation.h:492: note: previous declaration of
‘PartitionScheme’ was here
make[4]: *** [commit_ts.o] Error 1
make[4]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG_PWJ/postgresql/src/backend/access/transam'
make[3]: *** [transam-recursive] Error 2
make[3]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG_PWJ/postgresql/src/backend/access'
make[2]: *** [access-recursive] Error 2
make[2]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG_PWJ/postgresql/src/backend'
make[1]: *** [all-backend-recurse] Error 2
make[1]: Leaving directory
`/home/edb/Desktop/edb_work/WORKDB/PG_PWJ/postgresql/src'
make: *** [all-src-recurse] Error 2
PS : I am using - gcc (GCC) 4.4.7 20120313 (Red Hat 4.4.7-17)
I have commented below statement in src/include/catalog/partition.h file
and then tried to install, it worked fine.
/* typedef struct PartitionSchemeData *PartitionScheme; */
Thanks & Regards,
Rajkumar Raghuwanshi
../../../../src/include/catalog/partition.h:37: error: redefinition of
typedef ‘PartitionScheme’
../../../../src/include/nodes/relation.h:492: note: previous declaration of
‘PartitionScheme’ was here
[...]
PS : I am using - gcc (GCC) 4.4.7 20120313 (Red Hat 4.4.7-17)
Thanks for the report. For some reason, I am not getting these errors
with my compiler
[ashutosh@ubuntu regress]gcc --version
gcc (Ubuntu/Linaro 4.6.3-1ubuntu5) 4.6.3
Anyway, I have fixed it in the attached patch.
The patch is based on sources upto commit
commit 2a7f4f76434d82eb0d1b5f4f7051043e1dd3ee1a
Author: Heikki Linnakangas <heikki.linnakangas@iki.fi>
Date: Wed Sep 21 13:24:13 2016 +0300
and Amit Langote's set of patches posted on 15th Sept. 2016 [1]. /messages/by-id/e5c1c9cf-3f5a-c4d7-6047-7351147aaef9@lab.ntt.co.jp
There are few implementation details that need to be worked out like
1. adjust_partitionrel_attrs() calls adjust_appendrel_attrs() as many
times as the number of base relations in the join, possibly producing
a new expression tree in every call. It can be optimized to call
adjust_appendrel_attrs() only once. I will work on that if reviewers
agree that adjust_partitionrel_attrs() is needed and should be
optimized.
2. As mentioned in earlier mails, the paths parameterized by parent
partitioned table are translated to be parameterized by child
partitions. That code needs to support more kinds of paths. I will
work on that, if reviewers agree that the approach of translating
paths is acceptable.
3. Because of an issue with declarative partitioning patch [2]. /messages/by-id/CAFjFpRc=T+CjpGNkNSdOkHza8VAPb35bngaCdAzPgBkhijmJhg@mail.gmail.com
multi-level partition table tests are failing in partition_join.sql.
Those were not failing with an earlier set of patches supporting
declarative partitions. Those will be fixed based on the discussion in
that thread.
4. More tests for foreign tables as partitions and for multi-level
partitioned tables.
5. The tests use unpartitioned tables for verifying results. Those
tables and corresponding SQL statements will be removed once the tests
are finalised.
[1]: . /messages/by-id/e5c1c9cf-3f5a-c4d7-6047-7351147aaef9@lab.ntt.co.jp
[2]: . /messages/by-id/CAFjFpRc=T+CjpGNkNSdOkHza8VAPb35bngaCdAzPgBkhijmJhg@mail.gmail.com
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_v3.patchinvalid/octet-stream; name=pg_dp_join_v3.patchDownload
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index 1a60563..7b8406b 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -13,38 +13,41 @@
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/nbtree.h"
#include "access/sysattr.h"
#include "catalog/dependency.h"
+#include "catalog/heap.h"
#include "catalog/indexing.h"
#include "catalog/objectaddress.h"
#include "catalog/partition.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_inherits_fn.h"
#include "catalog/pg_opclass.h"
#include "catalog/pg_partitioned_table.h"
#include "catalog/pg_partitioned_table_fn.h"
#include "catalog/pg_type.h"
#include "executor/executor.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "nodes/parsenodes.h"
#include "optimizer/clauses.h"
+#include "optimizer/cost.h"
#include "optimizer/planmain.h"
#include "optimizer/var.h"
+#include "rewrite/rewriteManip.h"
#include "storage/lmgr.h"
#include "utils/array.h"
#include "utils/builtins.h"
#include "utils/datum.h"
#include "utils/memutils.h"
#include "utils/fmgroids.h"
#include "utils/inval.h"
#include "utils/lsyscache.h"
#include "utils/ruleutils.h"
#include "utils/rel.h"
@@ -208,20 +211,49 @@ typedef struct PartitionTreeNodeData
PartitionDesc pdesc;
Oid relid;
int index;
int offset;
int num_leaf_parts;
struct PartitionTreeNodeData *downlink;
struct PartitionTreeNodeData *next;
} PartitionTreeNodeData;
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting be partitioned in the same as the underlying relations.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ BoundCollection bounds; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
/* Support RelationBuildPartitionKey() */
static PartitionKey copy_partition_key(PartitionKey fromkey);
static KeyTypeCollInfo *copy_key_type_coll_info(int nkeycols,
KeyTypeCollInfo *tcinfo);
/* Support RelationBuildPartitionDesc() */
static int32 list_value_cmp(const void *a, const void *b, void *arg);
static int32 range_partition_cmp(const void *a, const void *b, void *arg);
/* Support check_new_partition_bound() */
@@ -870,20 +902,21 @@ RelationBuildPartitionDesc(Relation rel)
result->bounds->rangeinfo = rangeinfo;
break;
}
}
}
MemoryContextSwitchTo(oldcxt);
rel->rd_partdesc = result;
}
+
/*
* Are two partition bound collections logically equal?
*
* Used in the keep logic of relcache.c (ie, in RelationClearRelation()).
* This is also useful when b1 and b2 are bound collections of two separate
* relations, respectively, because BoundCollection is a canonical
* representation of a set partition bounds (for given partitioning strategy).
*/
bool
partition_bounds_equal(PartitionKey key,
@@ -2411,20 +2444,73 @@ make_range_bound(PartitionKey key, List *val, bool inclusive, bool lower)
bound->val[i] = datumCopy(val->constvalue,
key->tcinfo->typbyval[i],
key->tcinfo->typlen[i]);
i++;
}
}
return bound;
}
+static BoundCollection
+copy_bounds(BoundCollection src_bounds, PartitionKey key, int nparts)
+{
+ BoundCollection dst_bounds;
+ int i;
+
+ dst_bounds = (BoundCollection) palloc(sizeof(BoundCollectionData));
+
+ if (src_bounds->listinfo)
+ {
+ ListInfo *dst_li = (ListInfo *) palloc(sizeof(ListInfo));
+ ListInfo *src_li = src_bounds->listinfo;
+
+ Assert(!src_bounds->rangeinfo);
+ dst_bounds->rangeinfo = NULL;
+
+ /* Copy the ListInfo structure. */
+ dst_li->nvalues = src_li->nvalues;
+ dst_li->has_null = src_li->has_null;
+ dst_li->null_index = src_li->null_index;
+
+ dst_li->values = (Datum *) palloc(sizeof(Datum) * dst_li->nvalues);
+ dst_li->indexes = (int *) palloc(sizeof(int) * dst_li->nvalues);
+ for (i = 0; i < dst_li->nvalues; i++)
+ {
+ dst_li->values[i] = datumCopy(src_li->values[i],
+ key->tcinfo->typbyval[0],
+ key->tcinfo->typlen[0]);
+ dst_li->indexes[i] = src_li->indexes[i];
+ }
+
+ dst_bounds->listinfo = dst_li;
+ }
+ else
+ {
+ RangeInfo *dst_ri = (RangeInfo *) palloc(sizeof(RangeInfo));
+ RangeInfo *src_ri = src_bounds->rangeinfo;
+
+ Assert(!src_bounds->listinfo && src_bounds->rangeinfo);
+ dst_bounds->listinfo = NULL;
+
+ /* Copy RangeInfo structure. */
+ dst_ri = (RangeInfo *) palloc(sizeof(RangeInfo));
+ dst_ri->ranges = (PartitionRange **) palloc(sizeof(PartitionRange *) * nparts);
+ for (i = 0; i < nparts; i++)
+ dst_ri->ranges[i] = copy_range(src_ri->ranges[i], key);
+
+ dst_bounds->rangeinfo = dst_ri;
+ }
+
+ return dst_bounds;
+}
+
/*
* Make and return a copy of input PartitionRange.
*/
static PartitionRange *
copy_range(PartitionRange *src, PartitionKey key)
{
PartitionRange *result;
result = (PartitionRange *) palloc0(sizeof(PartitionRange));
result->lower = copy_range_bound(src->lower, key);
@@ -2647,10 +2733,210 @@ tuple_rightof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound)
static bool
tuple_leftof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound)
{
int32 cmpval = partition_range_tuple_cmp(key, tuple, bound->val);
if (!cmpval)
return !bound->lower ? bound->inclusive : !bound->inclusive;
return cmpval < 0;
}
+
+/*
+ * find_partition_scheme
+ * Find the "canonical" partition scheme for the given base table.
+ *
+ * The function searches the list of canonical partition schemes for one that
+ * exactly matches the partitioning properties of the given relation. If it
+ * does not find one, the function creates a canonical partition scheme
+ * structure and adds it to the list.
+ *
+ * For an umpartitioned table, it returns NULL.
+ */
+extern PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * It suffices to check the OID of support function as it always has
+ * two arguemnts and returns boolean. For types, it suffices to match
+ * the type id, mod and collation; len, byval and align are depedent on
+ * the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->tcinfo->typid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->tcinfo->typmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->tcinfo->typcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->bounds,
+ part_scheme->bounds, nparts))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->bounds = copy_bounds(part_desc->bounds, part_key,
+ part_scheme->nparts);
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ part_scheme->partopfamily[cnt_pks] = part_key->partopfamily[cnt_pks];
+ part_scheme->partopcintype[cnt_pks] = part_key->partopcintype[cnt_pks];
+ part_scheme->key_types[cnt_pks] = part_key->tcinfo->typid[cnt_pks];
+ part_scheme->key_typmods[cnt_pks] = part_key->tcinfo->typmod[cnt_pks];
+ part_scheme->key_collations[cnt_pks] = part_key->tcinfo->typcoll[cnt_pks];
+ }
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_keys
+ *
+ * For a base relation, construct an array of partition key expressions. Each
+ * partition key expression is stored as a single member list to accomodate
+ * more partition keys when relations are joined.
+ */
+extern List **
+build_baserel_partition_keys(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+
+ /* Store partition keys as single elements lists. */
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+
+ lc = list_head(part_key->partexprs);
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (!lc)
+ elog(ERROR, "wrong number of partition key expressions");
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
+
+/*
+ * Returns the number of partitions supported by the given partition scheme.
+ */
+extern int
+PartitionSchemeGetNumParts(PartitionScheme part_scheme)
+{
+ return part_scheme ? part_scheme->nparts : 0;
+}
+
+/*
+ * Returns the number of partition keys supported by the given partition
+ * scheme.
+ */
+extern int
+PartitionSchemeGetNumKeys(PartitionScheme part_scheme)
+{
+ return part_scheme ? part_scheme->partnatts : 0;
+}
+
+/*
+ * Return palloc'ed array of OIDs of partitions.
+ */
+extern Oid *
+PartitionDescGetPartOids(PartitionDesc part_desc)
+{
+ Oid *part_oids;
+ int cnt_parts;
+
+ if (!part_desc || part_desc->nparts <= 0)
+ return NULL;
+
+ part_oids = (Oid *) palloc(sizeof(Oid) * part_desc->nparts);
+ for (cnt_parts = 0; cnt_parts < part_desc->nparts; cnt_parts++)
+ part_oids[cnt_parts] = part_desc->oids[cnt_parts];
+
+ return part_oids;
+}
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 99b6bc8..1e43bab 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -13,20 +13,21 @@
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include <limits.h>
#include <math.h>
#include "access/sysattr.h"
#include "access/tsmapi.h"
+#include "catalog/partition.h"
#include "catalog/pg_class.h"
#include "catalog/pg_operator.h"
#include "catalog/pg_proc.h"
#include "foreign/fdwapi.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#ifdef OPTIMIZER_DEBUG
#include "nodes/print.h"
#endif
#include "optimizer/clauses.h"
@@ -37,20 +38,21 @@
#include "optimizer/plancat.h"
#include "optimizer/planner.h"
#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "rewrite/rewriteManip.h"
#include "utils/lsyscache.h"
+#include "utils/rel.h"
/* results of subquery_is_pushdown_safe */
typedef struct pushdown_safety_info
{
bool *unsafeColumns; /* which output columns are unsafe to use */
bool unsafeVolatile; /* don't push down volatile quals */
bool unsafeLeaky; /* don't push down leaky quals */
} pushdown_safety_info;
@@ -119,20 +121,24 @@ static void check_output_expressions(Query *subquery,
static void compare_tlist_datatypes(List *tlist, List *colTypes,
pushdown_safety_info *safetyInfo);
static bool targetIsInAllPartitionLists(TargetEntry *tle, Query *query);
static bool qual_is_pushdown_safe(Query *subquery, Index rti, Node *qual,
pushdown_safety_info *safetyInfo);
static void subquery_push_qual(Query *subquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels);
+static void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
/*
* make_one_rel
* Finds all possible access paths for executing a query, returning a
* single rel that represents the join of all base rels in the query.
*/
RelOptInfo *
make_one_rel(PlannerInfo *root, List *joinlist)
{
@@ -861,20 +867,48 @@ static void
set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte)
{
int parentRTindex = rti;
bool has_live_children;
double parent_rows;
double parent_size;
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ Oid *part_oids = NULL;
+ int nparts = 0;
+
+ /*
+ * For a partitioned relation, we will save the child RelOptInfos in parent
+ * RelOptInfo in the same the order as corresponding bounds/lists are
+ * stored in the partition scheme.
+ */
+ if (rel->part_scheme)
+ {
+ RangeTblEntry *rte = root->simple_rte_array[rel->relid];
+
+ /*
+ * We need not lock the relation since it was already locked, either by
+ * the rewriter or when expand_inherited_rtentry() added it to the
+ * query's rangetable.
+ */
+ Relation relation = heap_open(rte->relid, NoLock);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+
+ part_oids = PartitionDescGetPartOids(part_desc);
+ nparts = part_desc->nparts;
+
+ Assert(part_oids && nparts > 0);
+
+ rel->part_rels = (RelOptInfo **)palloc0(sizeof(RelOptInfo *) * nparts);
+ heap_close(relation, NoLock);
+ }
/*
* Initialize to compute size estimates for whole append relation.
*
* We handle width estimates by weighting the widths of different child
* rels proportionally to their number of rows. This is sensible because
* the use of width estimates is mainly to compute the total relation
* "footprint" if we have to sort or hash it. To do this, we sum the
* total equivalent size (in "double" arithmetic) and then divide by the
* total rowcount estimate. This is done separately for the total rel
@@ -892,36 +926,80 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
List *childquals;
Node *childqual;
ListCell *parentvars;
ListCell *childvars;
+ int cnt_parts;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
/*
* The child rel's RelOptInfo was already created during
* add_base_rels_to_query.
*/
childrel = find_base_rel(root, childRTindex);
+
+ /*
+ * Save topmost parent's relid. If the parent itself is a child of some
+ * other relation, use parent's topmost parent relids.
+ */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
/*
+ * For a partitioned table, save the child RelOptInfo at its
+ * appropriate place in the parent RelOptInfo.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+
+ /*
+ * Copy/Modify targetlist. Partition-wise join technique may consider
+ * an OUTER join of another child relation with this child relation.
+ * In that case, even if this child is deemed empty, we will require
+ * the targetlist of this child to construct the nullable side. Hence
+ * set the targetlist before we prove that the child is empty and stop
+ * processing further.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ appinfo);
+
+ /*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
* baserestrictinfo quals are needed before we can check for
* constraint exclusion; so do that first and then check to see if we
* can disregard this child.
*
* As of 8.4, the child rel's targetlist might contain non-Var
* expressions, which means that substitution into the quals could
* produce opportunities for const-simplification, and perhaps even
* pseudoconstant quals. To deal with this, we strip the RestrictInfo
@@ -953,38 +1031,25 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
if (relation_excluded_by_constraints(root, childrel, childRTE))
{
/*
* This child need not be scanned, so we can omit it from the
* appendrel.
*/
set_dummy_rel_pathlist(childrel);
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying join quals. */
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
appinfo);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo);
/*
* We have to make child entries in the EquivalenceClass data
* structures as well. This is needed either if the parent
* participates in some eclass joins (because we will want to consider
* inner-indexscan joins on the individual children) or if the parent
* has useful pathkeys (because we should try to build MergeAppend
* paths that produce those sort orderings).
*/
if (rel->has_eclass_joins || has_useful_pathkeys(root, rel))
@@ -1073,20 +1138,28 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
if (child_width <= 0)
child_width = get_typavgwidth(exprType(childvar),
exprTypmod(childvar));
Assert(child_width > 0);
parent_attrsizes[pndx] += child_width * childrel->rows;
}
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ Assert(rel->part_rels[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
* Save the finished size estimates.
*/
int i;
Assert(parent_rows > 0);
rel->rows = parent_rows;
rel->reltarget->width = rint(parent_size / parent_rows);
@@ -1115,41 +1188,32 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
/*
* set_append_rel_pathlist
* Build access paths for an "append relation"
*/
static void
set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte)
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
- * Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * Generate access paths for each member relation and remember the
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
/* Re-locate the child RTE and RelOptInfo */
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
childrel = root->simple_rel_array[childRTindex];
@@ -1170,20 +1234,57 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
/*
* If child is dummy, ignore it.
*/
if (IS_DUMMY_REL(childrel))
continue;
/*
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid = true;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (!live_childrels)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
* the unparameterized Append path we are constructing for the parent.
* If not, there's no workable unparameterized path.
*/
if (childrel->cheapest_total_path->param_info == NULL)
subpaths = accumulate_append_subpath(subpaths,
childrel->cheapest_total_path);
else
@@ -2188,20 +2289,22 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
* join_search_one_level. After that, we're done creating paths for
* the joinrel, so run set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
rel = (RelOptInfo *) lfirst(lc);
+ generate_partition_wise_join_paths(root, rel);
+
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
#ifdef OPTIMIZER_DEBUG
debug_print_rel(root, rel);
#endif
}
@@ -2851,20 +2954,73 @@ remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel)
* OK, we don't need it. Replace the expression with a NULL constant.
* Preserve the exposed type of the expression, in case something
* looks at the rowtype of the subquery's result.
*/
tle->expr = (Expr *) makeNullConst(exprType(texpr),
exprTypmod(texpr),
exprCollation(texpr));
}
}
+/*
+ * generate_partition_wise_join_paths
+ * Create appends paths containing partition-wise join paths for given
+ * join relation.
+ */
+static void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *live_children = NIL;
+ int cnt_part;
+ int nparts = PartitionSchemeGetNumParts(rel->part_scheme);
+
+ /* Handle only join relations. */
+ if (rel->reloptkind != RELOPT_JOINREL &&
+ rel->reloptkind != RELOPT_OTHER_JOINREL)
+ return;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || !rel->part_rels || IS_DUMMY_REL(rel))
+ return;
+
+ for (cnt_part = 0; cnt_part < nparts; cnt_part++)
+ {
+ RelOptInfo *child_rel = rel->part_rels[cnt_part];
+
+ /* Ignore dummy child. */
+ if (!IS_DUMMY_REL(child_rel))
+ {
+ /* Recursively collect the paths from child joinrel. */
+ generate_partition_wise_join_paths(root, child_rel);
+
+ /* Find the cheapest of the paths for this rel. */
+ set_cheapest(child_rel);
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ live_children = lappend(live_children, child_rel);
+ }
+ }
+
+ /*
+ * Create append paths by collecting sub paths from live children. Even if
+ * there are no live children, we should create an append path with no
+ * subpaths i.e. a dummy access path.
+ */
+ add_paths_to_append_rel(root, rel, live_children);
+
+ if (live_children)
+ pfree(live_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
*****************************************************************************/
#ifdef OPTIMIZER_DEBUG
static void
print_relids(PlannerInfo *root, Relids relids)
{
int x;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 2a49639..a23da1c 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -119,20 +119,21 @@ bool enable_seqscan = true;
bool enable_indexscan = true;
bool enable_indexonlyscan = true;
bool enable_bitmapscan = true;
bool enable_tidscan = true;
bool enable_sort = true;
bool enable_hashagg = true;
bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
typedef struct
{
PlannerInfo *root;
QualCost total;
} cost_qual_eval_context;
static List *extract_nonindex_conditions(List *qual_clauses, List *indexquals);
static MergeScanSelCache *cached_scansel(PlannerInfo *root,
RestrictInfo *rinfo,
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index 0e50ad5..73026a3 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2359,20 +2359,22 @@ eclass_useful_for_merging(PlannerInfo *root,
/*
* Note we don't test ec_broken; if we did, we'd need a separate code path
* to look through ec_sources. Checking the members anyway is OK as a
* possibly-overoptimistic heuristic.
*/
/* If specified rel is a child, we must consider the topmost parent rel */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->top_parent_relids;
else
relids = rel->relids;
/* If rel already includes all members of eclass, no point in searching */
if (bms_is_subset(eclass->ec_relids, relids))
return false;
/* To join, we need a member not in the given rel */
foreach(lc, eclass->ec_members)
{
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index cc7384f..db0e469 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -18,23 +18,29 @@
#include "executor/executor.h"
#include "foreign/fdwapi.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void match_unsorted_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void consider_parallel_nestloop(PlannerInfo *root,
RelOptInfo *joinrel,
RelOptInfo *outerrel,
RelOptInfo *innerrel,
@@ -125,38 +131,51 @@ add_paths_to_joinrel(PlannerInfo *root,
* directly to the parameter source rel instead of joining to the other
* input rel. (But see allow_star_schema_join().) This restriction
* reduces the number of parameterized paths we have to deal with at
* higher join levels, without compromising the quality of the resulting
* plan. We express the restriction as a Relids set that must overlap the
* parameterization of any proposed join path.
*/
foreach(lc, root->join_info_list)
{
SpecialJoinInfo *sjinfo = (SpecialJoinInfo *) lfirst(lc);
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between partitions, even if there is a SpecialJoinInfo node for the
+ * join between the topmost parents. Hence while calculating Relids set
+ * representing the restriction, consider relids of topmost parent of
+ * partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
/*
* SJ is relevant to this join if we have some part of its RHS
* (possibly not all of it), and haven't yet joined to its LHS. (This
* test is pretty simplistic, but should be sufficient considering the
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_righthand))
+ bms_overlap(joinrelids, sjinfo->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_lefthand));
}
/*
* However, when a LATERAL subquery is involved, there will simply not be
* any paths for the joinrel that aren't parameterized by whatever the
* subquery is parameterized by, unless its parameterization is resolved
* within the joinrel. So we might as well allow additional dependencies
@@ -272,20 +291,35 @@ try_nestloop_path(PlannerInfo *root,
Path *outer_path,
Path *inner_path,
List *pathkeys,
JoinType jointype,
JoinPathExtraData *extra)
{
Relids required_outer;
JoinCostWorkspace workspace;
/*
+ * An inner path parameterized by the parent relation of outer
+ * relation needs to be reparameterized by the outer relation to be used
+ * for parameterized nested loop join.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_for_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
* doesn't like the look of it, which could only happen if the nestloop is
* still parameterized.
*/
required_outer = calc_nestloop_required_outer(outer_path,
inner_path);
if (required_outer &&
((!bms_overlap(required_outer, extra->param_source_rels) &&
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..4c51dd2 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -7,38 +7,56 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* src/backend/optimizer/path/joinrels.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
+#include "catalog/partition.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
static void make_rels_by_clause_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static void make_rels_by_clauseless_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static SpecialJoinInfo * build_partition_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1,
+ List *append_rel_infos2);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
/*
* join_search_one_level
* Consider ways to produce join relations containing exactly 'level'
* jointree items. (This is one step of the dynamic-programming method
* embodied in standard_join_search.) Join rel nodes for each feasible
* combination of lower-level rels are created and returned in a list.
* Implementation paths are created for each such joinrel, too.
*
@@ -717,20 +735,44 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
/*
* If we've already proven this join is empty, we needn't consider any
* more paths for it.
*/
if (is_dummy_rel(joinrel))
{
bms_free(joinrelids);
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Create paths to join given input relation and add those to the given
+ * joinrel. The SpecialJoinInfo provides details about the join and the
+ * restrictlist contains the join clauses and the other clauses applicable
+ * for given pair of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
* is provably empty too; in which case throw away any previously computed
* paths and mark the join as dummy. (We do it this way since it's
* conceivable that dummy-ness of a multi-element join might only be
* noticeable for certain construction paths.)
*
* Also, a provably constant-false join restriction typically means that
* we can skip evaluating one or both sides of the join. We do this by
@@ -861,27 +903,22 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
mark_dummy_rel(rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
break;
default:
/* other values not expected here */
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
-
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
* a join-order restriction arising from special or lateral joins.
*
* In practice this is always used with have_relevant_joinclause(), and so
* could be merged with that function, but it seems clearer to separate the
* two concerns. We need this test because there are degenerate cases where
* a clauseless join must be performed to satisfy join-order restrictions.
* Also, if one rel has a lateral reference to the other, or both are needed
@@ -1242,10 +1279,314 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
/* constant NULL is as good as constant FALSE for our purposes */
if (con->constisnull)
return true;
if (!DatumGetBool(con->constvalue))
return true;
}
}
return false;
}
+
+/*
+ * If the join between the given two relations can be executed as
+ * partition-wise join create the join relations for partition-wise join,
+ * create paths for those and then create append paths to combine
+ * partition-wise join results.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ StringInfo rel1_desc;
+ StringInfo rel2_desc;
+ PartitionScheme part_scheme;
+
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, the given partition scheme can not be used for
+ * partition-wise join between these two relations.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = PartitionSchemeGetNumParts(part_scheme);
+ rel1_desc = makeStringInfo();
+ rel2_desc = makeStringInfo();
+
+ /* TODO: remove this notice when finalising the patch. */
+ outBitmapset(rel1_desc, rel1->relids);
+ outBitmapset(rel2_desc, rel2->relids);
+ elog(NOTICE, "join between relations %s and %s is considered for partition-wise join.",
+ rel1_desc->data, rel2_desc->data);
+
+ /*
+ * We allocate the array for child RelOptInfos till we find at least one
+ * join order which can use partition-wise join technique. If no join order
+ * can use partition-wise join technique, there are no child relations.
+ */
+
+ if (!joinrel->part_rels)
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create join relations for the partition relations, if they do not exist
+ * already. Add paths to those for the given pair of joining relations.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_joinrel;
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ List *join_aris;
+ List *ari1;
+ List *ari2;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ /*
+ * Gather the AppendRelInfos for base partition relations
+ * partiticipating in the given partition relations. We need them
+ * construct partition-wise join relation, special join info and
+ * restriction list by substituting the Var and relids from parent to
+ * child.
+ */
+ ari1 = find_appendrelinfos_by_relids(root, child_rel1->relids);
+ ari2 = find_appendrelinfos_by_relids(root, child_rel2->relids);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_partition_join_sjinfo(root, parent_sjinfo, ari1, ari2);
+
+ /* Construct the parent-child relid map for the join relation. */
+ join_aris = list_concat(ari1, ari2);
+
+ /*
+ * Construct restrictions applicable to the partition-wise join from
+ * those applicable to the join between the parents.
+ */
+ child_restrictlist = (List *) adjust_partitionrel_attrs(root,
+ (Node *)parent_restrictlist,
+ join_aris);
+
+ child_joinrel = joinrel->part_rels[cnt_parts];
+
+ /* Construct the join relation for given partition of the join. */
+ if (!child_joinrel)
+ {
+ child_joinrel = build_partition_join_rel(root, child_rel1,
+ child_rel2, joinrel,
+ child_sjinfo,
+ child_restrictlist,
+ join_aris);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ }
+
+ /*
+ * If we've already proven that this join is empty, we needn't consider
+ * any more paths for it.
+ */
+ if (is_dummy_rel(child_joinrel))
+ continue;
+
+ populate_joinrel_with_paths(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the partition themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+ }
+}
+
+/*
+ * Construct the SpecialJoinInfo for the partition-wise join using parents'
+ * special join info. Also, instead of
+ * constructing an sjinfo everytime, we should probably save it in
+ * root->join_info_list and search within it like join_is_legal?
+ */
+static SpecialJoinInfo *
+build_partition_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1, List *append_rel_infos2)
+{
+ SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo);
+ sjinfo->min_lefthand = adjust_partition_relids(sjinfo->min_lefthand,
+ append_rel_infos1);
+ sjinfo->min_righthand = adjust_partition_relids(sjinfo->min_righthand,
+ append_rel_infos2);
+ sjinfo->syn_lefthand = adjust_partition_relids(sjinfo->syn_lefthand,
+ append_rel_infos1);
+ sjinfo->syn_righthand = adjust_partition_relids(sjinfo->syn_righthand,
+ append_rel_infos2);
+
+ /* Replace the Var nodes of parent with those of children in expressions. */
+ sjinfo->semi_rhs_exprs = (List *) adjust_partitionrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ append_rel_infos2);
+ return sjinfo;
+}
+
+/*
+ * Substitute oldrelids with newrelids in the given Relids set. It recycles the
+ * given relids input.
+ */
+Relids
+adjust_partition_relids(Relids relids, List *append_rel_infos)
+{
+ ListCell *lc;
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *ari = lfirst(lc);
+
+ /* Remove old, add new */
+ if (bms_is_member(ari->parent_relid, relids))
+ {
+ relids = bms_del_member(relids, ari->parent_relid);
+ relids = bms_add_member(relids, ari->child_relid);
+ }
+ }
+ return relids;
+}
+
+/*
+ * Returns true if the given relations have equi-join clauses on all the
+ * corresponding partition keys.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks = PartitionSchemeGetNumKeys(part_scheme);
+ bool *pk_has_clause;
+
+ Assert(rel1->part_scheme == rel2->part_scheme);
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip non-equi-join clauses. */
+ if (!rinfo->can_join ||
+ rinfo->hashjoinoperator == InvalidOid ||
+ !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+ /*
+ * If clause of form rel1_expr op rel2_expr OR rel2_expr op rel1_expr,
+ * match the operands to the relations. Otherwise, the clause is
+ * not an equi-join between partition keys of joining relations.
+ */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ if (ipk1 == ipk2)
+ pk_has_clause[ipk1] = true;
+ }
+
+ /*
+ * If every pair of partition key from either of the joining relation has
+ * at least one equi-join clause associated with it, we have an equi-join
+ * between all corresponding partition keys.
+ */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * match_expr_to_partition_keys
+ *
+ * Find the partition key which is same as the given expression. If found,
+ * return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks = PartitionSchemeGetNumKeys(rel->part_scheme);
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() will have simplied if more
+ * than one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/path/pathkeys.c b/src/backend/optimizer/path/pathkeys.c
index 4436ac1..c8870c8 100644
--- a/src/backend/optimizer/path/pathkeys.c
+++ b/src/backend/optimizer/path/pathkeys.c
@@ -1081,26 +1081,38 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
RelOptInfo *joinrel)
{
List *pathkeys = NIL;
int nClauses = list_length(mergeclauses);
EquivalenceClass **ecs;
int *scores;
int necs;
ListCell *lc;
int j;
+ Relids relids;
/* Might have no mergeclauses */
if (nClauses == 0)
return NIL;
/*
+ * Code below scores equivalence classes by how many equivalence members
+ * can produce join clauses for this join relation. Equivalence members
+ * which do not cover the parents of a partition-wise join relation, can
+ * produce join clauses for partition-wise join relation.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
+ /*
* Make arrays of the ECs used by the mergeclauses (dropping any
* duplicates) and their "popularity" scores.
*/
ecs = (EquivalenceClass **) palloc(nClauses * sizeof(EquivalenceClass *));
scores = (int *) palloc(nClauses * sizeof(int));
necs = 0;
foreach(lc, mergeclauses)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
@@ -1126,21 +1138,21 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
continue;
/* compute score */
score = 0;
foreach(lc2, oeclass->ec_members)
{
EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
/* Potential future join partner? */
if (!em->em_is_const && !em->em_is_child &&
- !bms_overlap(em->em_relids, joinrel->relids))
+ !bms_overlap(em->em_relids, relids))
score++;
}
ecs[necs] = oeclass;
scores[necs] = score;
necs++;
}
/*
* Find out if we have all the ECs mentioned in query_pathkeys; if so we
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 32f4031..b221e2c 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -235,21 +235,22 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
const AttrNumber *reqColIdx,
bool adjust_tlist_in_place,
int *p_numsortkeys,
AttrNumber **p_sortColIdx,
Oid **p_sortOperators,
Oid **p_collations,
bool **p_nullsFirst);
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
static Material *make_material(Plan *lefttree);
static WindowAgg *make_windowagg(List *tlist, Index winref,
int partNumCols, AttrNumber *partColIdx, Oid *partOperators,
int ordNumCols, AttrNumber *ordColIdx, Oid *ordOperators,
int frameOptions, Node *startOffset, Node *endOffset,
Plan *lefttree);
static Group *make_group(List *tlist, List *qual, int numGroupCols,
@@ -1507,21 +1508,21 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
Plan *subplan;
/*
* We don't want any excess columns in the sorted tuples, so request a
* smaller tlist. Otherwise, since Sort doesn't project, tlist
* requirements pass through.
*/
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
return plan;
}
/*
* create_group_plan
*
* Create a Group plan for 'best_path' and (recursively) plans
@@ -3517,31 +3518,33 @@ create_mergejoin_plan(PlannerInfo *root,
List *innerpathkeys;
int nClauses;
Oid *mergefamilies;
Oid *mergecollations;
int *mergestrategies;
bool *mergenullsfirst;
int i;
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
* inputs. However, if we're intending to sort an input's result, it's
* best to request a small tlist so we aren't sorting more data than
* necessary.
*/
- outer_plan = create_plan_recurse(root, best_path->jpath.outerjoinpath,
+ outer_plan = create_plan_recurse(root, outer_path,
(best_path->outersortkeys != NIL) ? CP_SMALL_TLIST : 0);
- inner_plan = create_plan_recurse(root, best_path->jpath.innerjoinpath,
+ inner_plan = create_plan_recurse(root, inner_path,
(best_path->innersortkeys != NIL) ? CP_SMALL_TLIST : 0);
/* Sort join qual clauses into best execution order */
/* NB: do NOT reorder the mergeclauses */
joinclauses = order_qual_clauses(root, best_path->jpath.joinrestrictinfo);
/* Get the join qual clauses (in plain expression form) */
/* Any pseudoconstant clauses are ignored here */
if (IS_OUTER_JOIN(best_path->jpath.jointype))
{
@@ -3573,48 +3576,52 @@ create_mergejoin_plan(PlannerInfo *root,
otherclauses = (List *)
replace_nestloop_params(root, (Node *) otherclauses);
}
/*
* Rearrange mergeclauses, if needed, so that the outer variable is always
* on the left; mark the mergeclause restrictinfos with correct
* outer_is_left status.
*/
mergeclauses = get_switched_clauses(best_path->path_mergeclauses,
- best_path->jpath.outerjoinpath->parent->relids);
+ outer_path->parent->relids);
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
outerpathkeys = best_path->outersortkeys;
}
else
- outerpathkeys = best_path->jpath.outerjoinpath->pathkeys;
+ outerpathkeys = outer_path->pathkeys;
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
innerpathkeys = best_path->innersortkeys;
}
else
- innerpathkeys = best_path->jpath.innerjoinpath->pathkeys;
+ innerpathkeys = inner_path->pathkeys;
/*
* If specified, add a materialize node to shield the inner plan from the
* need to handle mark/restore.
*/
if (best_path->materialize_inner)
{
Plan *matplan = (Plan *) make_material(inner_plan);
/*
@@ -5330,25 +5337,25 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any
* further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
exprvars = pull_var_clause((Node *) sortexpr,
PVC_INCLUDE_AGGREGATES |
PVC_INCLUDE_WINDOWFUNCS |
PVC_INCLUDE_PLACEHOLDERS);
foreach(k, exprvars)
{
if (!tlist_member_ignore_relabel(lfirst(k), tlist))
@@ -5445,57 +5452,58 @@ find_ec_member_for_tle(EquivalenceClass *ec,
Expr *emexpr;
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
emexpr = em->em_expr;
while (emexpr && IsA(emexpr, RelabelType))
emexpr = ((RelabelType *) emexpr)->arg;
if (equal(emexpr, tlexpr))
return em;
}
return NULL;
}
/*
* make_sort_from_pathkeys
* Create sort plan to sort according to given pathkeys
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
Oid *sortOperators;
Oid *collations;
bool *nullsFirst;
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
&sortColIdx,
&sortOperators,
&collations,
&nullsFirst);
/* Now build the Sort node */
return make_sort(lefttree, numsortkeys,
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 193b2c9..10335d2 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -1873,20 +1873,71 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
appinfo);
}
result = (Node *) newnode;
}
else
result = adjust_appendrel_attrs_mutator(node, &context);
return result;
}
+/*
+ * find_appendrelinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appendrelinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *ari_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *ari = lfirst(lc);
+
+ if (bms_is_member(ari->child_relid, relids))
+ ari_list = lappend(ari_list, ari);
+ }
+
+ Assert(list_length(ari_list) == bms_num_members(relids));
+ return ari_list;
+}
+
+/*
+ * adjust_partitionrel_attrs
+ * Replace the Var nodes in given node with the corresponding Var nodes
+ * of the child. Given list of AppendRelInfo nodes holds the mapping
+ * between parent and child Var nodes.
+ *
+ * While doing so, we need to make sure to translate non-expression information
+ * in nodes like RestrictInfo.
+ */
+Node *
+adjust_partitionrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos)
+{
+ ListCell *lc;
+
+ /*
+ * TODO: Instead of copying and mutating the trees one child relation at a
+ * time, we should be able to do this en-masse for all the partitions
+ * involved.
+ */
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *append_rel_info = lfirst(lc);
+ node = adjust_appendrel_attrs(root, node, append_rel_info);
+ }
+
+ return node;
+}
+
static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
AppendRelInfo *appinfo = context->appinfo;
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index abb7507..ba64329 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -16,21 +16,23 @@
#include <math.h>
#include "miscadmin.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
#include "utils/selfuncs.h"
typedef enum
{
COSTS_EQUAL, /* path costs are fuzzily equal */
COSTS_BETTER1, /* first path is cheaper than second */
@@ -3202,10 +3204,160 @@ reparameterize_path(PlannerInfo *root, Path *path,
rel,
spath->subpath,
spath->path.pathkeys,
required_outer);
}
default:
break;
}
return NULL;
}
+
+/*
+ * reparameterize_path_for_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ */
+Path *
+reparameterize_path_for_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+
+ /*
+ * If the path is not parameterized by parent of the given relation, it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appendrelinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = adjust_partition_relids(bms_copy(old_ppi->ppi_req_outer),
+ child_aris);
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = (List *) adjust_partitionrel_attrs(root,
+ (Node *) old_ppi->ppi_clauses,
+ child_aris);
+
+ /* Adjust the path target. */
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_partitionrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ new_path->param_info = new_ppi;
+
+ /*
+ * Change parameterization of sub paths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_for_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_for_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = (List *) adjust_partitionrel_attrs(root,
+ (Node *) jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_for_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexquals = (List *) adjust_partitionrel_attrs(root,
+ (Node *) ipath->indexquals,
+ child_aris);
+ ipath->indexquals = (List *) adjust_partitionrel_attrs(root,
+ (Node *) ipath->indexorderbys,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index f8bfa4b..a3f27d1 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -404,20 +404,34 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
else
{
rel->serverid = InvalidOid;
rel->fdwroutine = NULL;
}
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation);
+ /*
+ * Lookup partition scheme for the given relation. Only parent relations
+ * can be partitioned.
+ */
+ if (inhparent)
+ rel->part_scheme = find_partition_scheme(root, relation);
+ else
+ rel->part_scheme = NULL;
+
+ if (rel->part_scheme)
+ rel->partexprs = build_baserel_partition_keys(relation, rel->relid);
+ else
+ rel->partexprs = NULL;
+
heap_close(relation, NoLock);
/*
* Allow a plugin to editorialize on the info we obtained from the
* catalogs. Actions might include altering the assumed relation size,
* removing an index, or adding a hypothetical index to the indexlist.
*/
if (get_relation_info_hook)
(*get_relation_info_hook) (root, relationObjectId, inhparent, rel);
}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index deef560..bd0b956 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -8,29 +8,35 @@
*
*
* IDENTIFICATION
* src/backend/optimizer/util/relnode.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
+#include "catalog/partition.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
+#include "nodes/makefuncs.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
{
Relids join_relids; /* hash key --- MUST BE FIRST */
RelOptInfo *join_rel;
} JoinHashEntry;
static void build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel);
@@ -40,20 +46,25 @@ static List *build_joinrel_restrictlist(PlannerInfo *root,
RelOptInfo *inner_rel);
static void build_joinrel_joinlist(RelOptInfo *joinrel,
RelOptInfo *outer_rel,
RelOptInfo *inner_rel);
static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_restrictlist);
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
/*
* setup_simple_rel_arrays
* Prepare the arrays we use for quickly accessing base relations.
*/
void
setup_simple_rel_arrays(PlannerInfo *root)
{
Index rti;
@@ -130,20 +141,24 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
rel->serverid = InvalidOid;
rel->userid = rte->checkAsUser;
rel->useridiscurrent = false;
rel->fdwroutine = NULL;
rel->fdw_private = NULL;
rel->baserestrictinfo = NIL;
rel->baserestrictcost.startup = 0;
rel->baserestrictcost.per_tuple = 0;
rel->joininfo = NIL;
rel->has_eclass_joins = false;
+ rel->part_scheme = NULL;
+ rel->partexprs = NULL;
+ rel->top_parent_relids = NULL;
+ rel->part_rels = NULL;
/* Check type of rtable entry */
switch (rte->rtekind)
{
case RTE_RELATION:
/* Table --- retrieve statistics from the system catalogs */
get_relation_info(root, rte->relid, rte->inh, rel);
break;
case RTE_SUBQUERY:
case RTE_FUNCTION:
@@ -307,20 +322,70 @@ find_join_rel(PlannerInfo *root, Relids relids)
if (bms_equal(rel->relids, relids))
return rel;
}
}
return NULL;
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
*
* 'joinrelids' is the Relids set that uniquely identifies the join
* 'outer_rel' and 'inner_rel' are relation nodes for the relations to be
* joined
* 'sjinfo': join context info
* 'restrictlist_ptr': result variable. If not NULL, *restrictlist_ptr
* receives the list of RestrictInfo nodes that apply to this
@@ -356,21 +421,25 @@ build_join_rel(PlannerInfo *root,
joinrel,
outer_rel,
inner_rel);
return joinrel;
}
/*
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
+
+ Assert(!IS_OTHER_REL(outer_rel->reloptkind) &&
+ !IS_OTHER_REL(inner_rel->reloptkind));
joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
joinrel->consider_startup = (root->tuple_fraction > 0);
joinrel->consider_param_startup = false;
joinrel->consider_parallel = false;
joinrel->reltarget = create_empty_pathtarget();
joinrel->pathlist = NIL;
joinrel->ppilist = NIL;
joinrel->partial_pathlist = NIL;
@@ -402,61 +471,27 @@ build_join_rel(PlannerInfo *root,
joinrel->serverid = InvalidOid;
joinrel->userid = InvalidOid;
joinrel->useridiscurrent = false;
joinrel->fdwroutine = NULL;
joinrel->fdw_private = NULL;
joinrel->baserestrictinfo = NIL;
joinrel->baserestrictcost.startup = 0;
joinrel->baserestrictcost.per_tuple = 0;
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Computer information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
* this join (ie, are needed for higher joinclauses or final output).
*
* NOTE: the tlist order for a join rel will depend on which pair of outer
* and inner rels we first try to build it from. But the contents should
* be the same regardless.
*/
build_joinrel_tlist(root, joinrel, outer_rel);
@@ -468,20 +503,24 @@ build_join_rel(PlannerInfo *root,
* sets of any PlaceHolderVars computed here to direct_lateral_relids, so
* now we can finish computing that. This is much like the computation of
* the transitively-closed lateral_relids in min_join_parameterization,
* except that here we *do* have to consider the added PHVs.
*/
joinrel->direct_lateral_relids =
bms_del_members(joinrel->direct_lateral_relids, joinrel->relids);
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
* for set_joinrel_size_estimates().)
*/
restrictlist = build_joinrel_restrictlist(root, joinrel,
outer_rel, inner_rel);
if (restrictlist_ptr)
*restrictlist_ptr = restrictlist;
build_joinrel_joinlist(joinrel, outer_rel, inner_rel);
@@ -510,58 +549,170 @@ build_join_rel(PlannerInfo *root,
* assume this doesn't matter, because we should hit all the same baserels
* and joinclauses while building up to this joinrel no matter which we
* take; therefore, we should make the same decision here however we get
* here.
*/
if (inner_rel->consider_parallel && outer_rel->consider_parallel &&
is_parallel_safe(root, (Node *) restrictlist) &&
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the query's PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
* to the appropriate sublist. Note: you might think the Assert on number
* of members should be for equality, but some of the level 1 rels might
* have been joinrels already, so we can only assert <=.
*/
if (root->join_rel_level)
{
Assert(root->join_cur_level > 0);
Assert(root->join_cur_level <= bms_num_members(joinrel->relids));
root->join_rel_level[root->join_cur_level] =
lappend(root->join_rel_level[root->join_cur_level], joinrel);
}
return joinrel;
}
/*
+ * build_partition_join_rel
+ * Returns relation entry corresponding to the of join between two given
+ * partition relations.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of partition relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for join between the partitions
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_aris': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_partition_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist,
+ List *join_aris)
+{
+ List *tmp_exprs;
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel->reloptkind) &&
+ IS_OTHER_REL(inner_rel->reloptkind));
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Computer information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /*
+ * Produce partition-wise joinrel's targetlist by translating the parent
+ * joinrel's targetlist. This will also include the required placeholder
+ * Vars.
+ */
+ joinrel->reltarget = copy_pathtarget(parent_joinrel->reltarget);
+ tmp_exprs = joinrel->reltarget->exprs;
+ joinrel->reltarget->exprs = (List *) adjust_partitionrel_attrs(root, (Node *) tmp_exprs,
+ join_aris);
+
+ /*
+ * Lateral relids directly referred in this relation will be same as that
+ * of the parent relation.
+ */
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ joinrel->joininfo = (List *) adjust_partitionrel_attrs(root,
+ (Node *) parent_joinrel->joininfo,
+ join_aris);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, sjinfo->jointype);
+
+ /*
+ * Set estimates of the joinrel's size.
+ */
+ set_joinrel_size_estimates(root, joinrel, outer_rel, inner_rel, sjinfo,
+ restrictlist);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
+/*
* min_join_parameterization
*
* Determine the minimum possible parameterization of a joinrel, that is, the
* set of other rels it contains LATERAL references to. We save this value in
* the join's RelOptInfo. This function is split out of build_join_rel()
* because join_is_legal() needs the value to check a prospective join.
*/
Relids
min_join_parameterization(PlannerInfo *root,
Relids joinrelids,
@@ -1313,10 +1464,92 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
ppi->ppi_req_outer = required_outer;
ppi->ppi_rows = 0;
ppi->ppi_clauses = NIL;
appendrel->ppilist = lappend(appendrel->ppilist, ppi);
return ppi;
}
+
+/*
+ * Adds given join relation to the joinrel list and also to the hashtable if
+ * there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
+ * Set up partitioning scheme and partition keys for a join between given two
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /*
+ * Nothing to do if
+ * a. partition-wise join is disabled.
+ * b. joining relations are not partitioned.
+ * c. partitioning schemes do not match.
+ */
+ if (!enable_partition_wise_join ||
+ !outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel and thus we
+ * should not see partition scheme, partition keys and array for storing
+ * child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ num_pks = PartitionSchemeGetNumKeys(outer_rel->part_scheme);
+
+ /* Join relation is partitioned in the same way as the joining relation. */
+ joinrel->part_scheme = outer_rel->part_scheme;
+
+ /*
+ * Collect the partition key expressions. An OUTER join will produce rows
+ * where the partition key columns of inner side are NULL and may not fit
+ * the partitioning scheme with inner partition keys. Since two NULL values
+ * are not considered equal, an equi-join involing inner partition keys
+ * still prohibits cross-partition joins while joining with another
+ * similarly partitioned relation.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 56943f2..16b2eac 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3405,21 +3405,23 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
else
{
/* not time to process varinfo2 yet */
newvarinfos = lcons(varinfo2, newvarinfos);
}
}
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
if (rel->tuples > 0)
{
/*
* Clamp to size of rel, or size of rel / 10 if multiple Vars. The
* fudge factor is because the Vars are probably correlated but we
* don't know by how much. We should never clamp to less than the
* largest ndistinct value for any of the Vars, though, since
* there will surely be at least that many groups.
*/
double clamp = rel->tuples;
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index ce4eef9..edc7e58 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -870,20 +870,29 @@ static struct config_bool ConfigureNamesBool[] =
},
{
{"enable_hashjoin", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of hash join plans."),
NULL
},
&enable_hashjoin,
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
gettext_noop("Enables genetic query optimization."),
gettext_noop("This algorithm attempts to do planning without "
"exhaustive searching.")
},
&enable_geqo,
true,
NULL, NULL, NULL
diff --git a/src/include/catalog/partition.h b/src/include/catalog/partition.h
index 81a4b91..3c59619 100644
--- a/src/include/catalog/partition.h
+++ b/src/include/catalog/partition.h
@@ -41,20 +41,24 @@ typedef struct BoundCollectionData *BoundCollection;
*/
typedef struct PartitionDescData
{
int nparts; /* Number of partitions */
Oid *oids; /* OIDs of partitions */
BoundCollection bounds; /* collection of list or range bounds */
} PartitionDescData;
typedef struct PartitionDescData *PartitionDesc;
typedef struct PartitionTreeNodeData *PartitionTreeNode;
+typedef struct PartitionSchemeData *PartitionScheme;
+
+/* Include here to avoid circular dependency with relation.h. */
+struct PlannerInfo;
/* relcache support for partition key information */
extern void RelationBuildPartitionKey(Relation relation);
/* Partition key inquiry functions */
extern int get_partition_key_strategy(PartitionKey key);
extern int get_partition_key_natts(PartitionKey key);
extern List *get_partition_key_exprs(PartitionKey key);
/* Partition key inquiry functions - for a given column */
@@ -77,11 +81,18 @@ extern List *get_qual_from_partbound(Relation rel, Relation parent, Node *bound)
extern List *RelationGetPartitionQual(Relation rel, bool recurse);
/* For tuple routing */
extern PartitionTreeNode RelationGetPartitionTreeNode(Relation rel);
extern List *get_leaf_partition_oids_v2(PartitionTreeNode ptnode);
extern int get_partition_for_tuple(PartitionTreeNode ptnode,
TupleTableSlot *slot,
EState *estate,
Oid *failed_at);
+extern List **build_baserel_partition_keys(Relation relation, Index varno);
+extern PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+extern int PartitionSchemeGetNumParts(PartitionScheme part_scheme);
+extern int PartitionSchemeGetNumKeys(PartitionScheme part_scheme);
+extern Oid *PartitionDescGetPartOids(PartitionDesc part_desc);
+
#endif /* PARTITION_H */
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 3a1255a..b00eedc 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -8,20 +8,21 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* src/include/nodes/relation.h
*
*-------------------------------------------------------------------------
*/
#ifndef RELATION_H
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "storage/block.h"
/*
* Relids
* Set of relation identifiers (indexes into the rangetable).
*/
@@ -256,20 +257,23 @@ typedef struct PlannerInfo
List *query_pathkeys; /* desired pathkeys for query_planner() */
List *group_pathkeys; /* groupClause pathkeys, if any */
List *window_pathkeys; /* pathkeys of bottom window, if any */
List *distinct_pathkeys; /* distinctClause pathkeys, if any */
List *sort_pathkeys; /* sortClause pathkeys, if any */
List *initial_rels; /* RelOptInfos we are now trying to join */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
/* Use fetch_upper_rel() to get any particular upper rel */
List *upper_rels[UPPERREL_FINAL + 1]; /* upper-rel RelOptInfos */
/* Result tlists chosen by grouping_planner for upper-stage processing */
struct PathTarget *upper_targets[UPPERREL_FINAL + 1];
/*
* grouping_planner passes back its final processed targetlist here, for
* use in relabeling the topmost tlist of the finished Plan.
*/
@@ -345,20 +349,26 @@ typedef struct PlannerInfo
* is present in the query join tree but the members are not. The member
* RTEs and otherrels are used to plan the scans of the individual tables or
* subqueries of the append set; then the parent baserel is given Append
* and/or MergeAppend paths comprising the best paths for the individual
* member rels. (See comments for AppendRelInfo for more information.)
*
* At one time we also made otherrels to represent join RTEs, for use in
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing pair-wise joins between partitions of
+ * partitioned tables. These relations are not added to join_rel_level lists
+ * as they are not joined directly by the dynamic programming algorithm.
+ * Adding these two join_rel_level list also means that top level list has more
+ * than one join relation, which is symantically incorrect.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
* fields always hold Paths showing ways to do that processing step.
*
* Lastly, there is a RelOptKind for "dead" relations, which are base rels
* that we have proven we don't need to join after all.
*
* Parts of this data structure are specific to various scan and join
* mechanisms. It didn't seem worth creating new node types for them.
@@ -464,24 +474,29 @@ typedef struct PlannerInfo
* We store baserestrictcost in the RelOptInfo (for base relations) because
* we know we will need it at least once (to price the sequential scan)
* and may need it multiple times to price index scans.
*----------
*/
typedef enum RelOptKind
{
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(reloptkind) \
+ ((reloptkind) == RELOPT_OTHER_MEMBER_REL || \
+ (reloptkind) == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
RelOptKind reloptkind;
/* all relations included in this RelOptInfo */
Relids relids; /* set of base relids (rangetable indexes) */
/* size estimates generated by planner */
@@ -535,20 +550,37 @@ typedef struct RelOptInfo
struct FdwRoutine *fdwroutine;
void *fdw_private;
/* used by various scans and joins: */
List *baserestrictinfo; /* RestrictInfo structures (if base
* rel) */
QualCost baserestrictcost; /* cost of evaluating the above */
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations, joins or base relations. NULL otherwise. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there can be as many elements
+ * as there are number of joining
+ * relations.
+ */
+
+ /* Set only for "other" base or join relations. */
+ Relids top_parent_relids;
} RelOptInfo;
/*
* IndexOptInfo
* Per-index information for planning/optimization
*
* indexkeys[], indexcollations[], opfamily[], and opcintype[]
* each have ncolumns entries.
*
* sortopfamily[], reverse_sort[], and nulls_first[] likewise have
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..1069726 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -59,20 +59,21 @@ extern bool enable_seqscan;
extern bool enable_indexscan;
extern bool enable_indexonlyscan;
extern bool enable_bitmapscan;
extern bool enable_tidscan;
extern bool enable_sort;
extern bool enable_hashagg;
extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
double index_pages, PlannerInfo *root);
extern void cost_seqscan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_samplescan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_index(IndexPath *path, PlannerInfo *root,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 71d9154..2ab31d3 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -222,20 +222,22 @@ extern ModifyTablePath *create_modifytable_path(PlannerInfo *root,
List *rowMarks, OnConflictExpr *onconflict,
int epqParam);
extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_for_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
*/
extern void setup_simple_rel_arrays(PlannerInfo *root);
extern RelOptInfo *build_simple_rel(PlannerInfo *root, int relid,
RelOptKind reloptkind);
extern RelOptInfo *find_base_rel(PlannerInfo *root, int relid);
extern RelOptInfo *find_join_rel(PlannerInfo *root, Relids relids);
extern RelOptInfo *build_join_rel(PlannerInfo *root,
@@ -260,12 +262,17 @@ extern ParamPathInfo *get_baserel_parampathinfo(PlannerInfo *root,
Relids required_outer);
extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
RelOptInfo *joinrel,
Path *outer_path,
Path *inner_path,
SpecialJoinInfo *sjinfo,
Relids required_outer,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_partition_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, SpecialJoinInfo *sjinfo,
+ List *restrictlist, List *join_aris);
+extern void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..a799428 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -212,11 +212,13 @@ extern List *make_inner_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
List *outer_pathkeys);
extern List *truncate_useless_pathkeys(PlannerInfo *root,
RelOptInfo *rel,
List *pathkeys);
extern bool has_useful_pathkeys(PlannerInfo *root, RelOptInfo *rel);
extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+extern Relids adjust_partition_relids(Relids relids, List *append_rel_infos);
+
#endif /* PATHS_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index fb35b68..7b149c3 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -21,20 +21,23 @@
/*
* prototypes for prepjointree.c
*/
extern void pull_up_sublinks(PlannerInfo *root);
extern void inline_set_returning_functions(PlannerInfo *root);
extern void pull_up_subqueries(PlannerInfo *root);
extern void flatten_simple_union_all(PlannerInfo *root);
extern void reduce_outer_joins(PlannerInfo *root);
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
+extern Node *adjust_partitionrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos);
+extern List *find_appendrelinfos_by_relids(PlannerInfo *root, Relids relids);
/*
* prototypes for prepqual.c
*/
extern Node *negate_clause(Node *node);
extern Expr *canonicalize_qual(Expr *qual);
/*
* prototypes for prepsecurity.c
*/
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..0eecade
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,7031 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a = 1 AND a = 2) t1 FULL JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (((t1.a + t1.b) / 2) = ((t2.b + t2.a) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: (((t1_1.a + t1_1.b) / 2) = ((t2_1.b + t2_1.a) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: (((t1_2.a + t1_2.b) / 2) = ((t2_2.b + t2_2.a) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Sort Key: prt1_e_p1.a, prt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Hash Cond: (((prt1_e_p1.a + prt1_e_p1.b) / 2) = ((prt2_e_p1.b + prt2_e_p1.a) / 2))
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt1_e_p1.b
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ -> Seq Scan on public.prt2_e_p1
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ Filter: ((prt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt2_e_p2.b, prt2_e_p2.c
+ Hash Cond: (((prt1_e_p2.a + prt1_e_p2.b) / 2) = ((prt2_e_p2.b + prt2_e_p2.a) / 2))
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt1_e_p2.b
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ -> Seq Scan on public.prt2_e_p2
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ Filter: ((prt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt2_e_p3.b, prt2_e_p3.c
+ Hash Cond: (((prt1_e_p3.a + prt1_e_p3.b) / 2) = ((prt2_e_p3.b + prt2_e_p3.a) / 2))
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt1_e_p3.b
+ Filter: ((prt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ -> Seq Scan on public.prt2_e_p3
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ Filter: ((prt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t2.a, t2.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t2_1.a, t2_1.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t2_2.a, t2_2.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 18) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 22) and (b 9) is considered for partition-wise join.
+NOTICE: join between relations (b 26) and (b 13) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.b = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text) AND ((t1_1.b + t1_1.a) = (t2_1.a + t2_1.b)))
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.b = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text) AND ((t1_2.b + t1_2.a) = (t2_2.a + t2_2.b)))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
+ Hash Cond: ((t1_3.a = t2_3.b) AND (t1_3.b = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text) AND ((t1_3.b + t1_3.a) = (t2_3.a + t2_3.b)))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Hash
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: ((t2_3.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_4.b, t2_4.c, t1_4.a, t1_4.c
+ Hash Cond: ((t1_4.a = t2_4.b) AND (t1_4.b = t2_4.a) AND ((t1_4.c)::text = (t2_4.c)::text) AND ((t1_4.b + t1_4.a) = (t2_4.a + t2_4.b)))
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Hash
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: ((t2_4.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_5.b, t2_5.c, t1_5.a, t1_5.c
+ Hash Cond: ((t1_5.a = t2_5.b) AND (t1_5.b = t2_5.a) AND ((t1_5.c)::text = (t2_5.c)::text) AND ((t1_5.b + t1_5.a) = (t2_5.a + t2_5.b)))
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Hash
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: ((t2_5.b % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 18) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 22) and (b 9) is considered for partition-wise join.
+NOTICE: join between relations (b 26) and (b 13) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Sort Key: prt1_l_p1_p1.a, prt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt2_l_p1_p2.b, prt2_l_p1_p2.c
+ Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.c = t1.c) AND (t2.a = t1.a))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.c = t1_1.c) AND (t2_1.a = t1_1.a))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.c = t1_2.c) AND (t2_2.a = t1_2.a))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, avg(plt2_p1.b), plt2_p1.c
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, sum((25)), avg(plt2_p1.b), plt2_p1.c, avg((50))
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (25), (50)
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c, 25
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c, (50)
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c, 50
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, (25), (50)
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c, 25
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c, (50)
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c, 50
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, (25), (50)
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c, 25
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c, (50)
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c, 50
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (avg(t2.b)), t2.c
+ Sort Key: t1.c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, avg(t2.b), t2.c
+ Group Key: t1.c, t2.c
+ -> Result
+ Output: t1.c, t2.c, t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(20 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Left Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Left Join
+ Output: t1_1.a, t1_1.c, t2.b, t2.c
+ Hash Cond: (t1_1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(a)), c, (sum(t2.b)), t2.c
+ Sort Key: c, t2.c
+ -> HashAggregate
+ Output: sum(a), c, sum(t2.b), t2.c
+ Group Key: c, t2.c
+ -> Result
+ Output: c, t2.c, a, t2.b
+ -> Append
+ -> Hash Left Join
+ Output: t2.b, t2.c, a, c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1.a, t1.c
+ Hash Cond: (t1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (ltrim(t1.c, 'A'::text) = ltrim(t2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (ltrim(t1_1.c, 'A'::text) = ltrim(t2_1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (ltrim(t1_2.c, 'A'::text) = ltrim(t2_2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Sort Key: plt1_e_p1.a, plt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Hash Cond: ((plt1_e_p1.a = plt2_e_p1.b) AND (ltrim(plt1_e_p1.c, 'A'::text) = ltrim(plt2_e_p1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ -> Seq Scan on public.plt2_e_p1
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ Filter: ((plt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p2.a, plt1_e_p2.c, plt2_e_p2.b, plt2_e_p2.c
+ Hash Cond: ((plt1_e_p2.a = plt2_e_p2.b) AND (ltrim(plt1_e_p2.c, 'A'::text) = ltrim(plt2_e_p2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ -> Seq Scan on public.plt2_e_p2
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ Filter: ((plt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p3.a, plt1_e_p3.c, plt2_e_p3.b, plt2_e_p3.c
+ Hash Cond: ((plt1_e_p3.a = plt2_e_p3.b) AND (ltrim(plt1_e_p3.c, 'A'::text) = ltrim(plt2_e_p3.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ -> Seq Scan on public.plt2_e_p3
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ Filter: ((plt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 1 3) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2 3) and (b 1) is considered for partition-wise join.
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1 2) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2 4) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 1 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 4) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((t3.a = t2.b) AND ((ltrim(t3.c, 'A'::text)) = t2.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (ltrim(t3.c, 'A'::text))
+ Sort Key: t3.a, (ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ltrim(t3.c, 'A'::text)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((t3_1.a = t2_1.b) AND ((ltrim(t3_1.c, 'A'::text)) = t2_1.c))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (ltrim(t3_1.c, 'A'::text))
+ Sort Key: t3_1.a, (ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ltrim(t3_1.c, 'A'::text)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((t3_2.a = t2_2.b) AND ((ltrim(t3_2.c, 'A'::text)) = t2_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (ltrim(t3_2.c, 'A'::text))
+ Sort Key: t3_2.a, (ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ltrim(t3_2.c, 'A'::text)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: ((ltrim(t1_6.c, 'A'::text)) = t1_3.c)
+ -> Sort
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Sort Key: (ltrim(t1_6.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Sort
+ Output: t1_3.c
+ Sort Key: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: ((ltrim(t1_7.c, 'A'::text)) = t1_4.c)
+ -> Sort
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Sort Key: (ltrim(t1_7.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Sort
+ Output: t1_4.c
+ Sort Key: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: ((ltrim(t1_8.c, 'A'::text)) = t1_5.c)
+ -> Sort
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Sort Key: (ltrim(t1_8.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+ -> Sort
+ Output: t1_5.c
+ Sort Key: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+(88 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (ltrim(t3.c, 'A'::text) = t2.c)
+ Join Filter: (t2.b = t3.a)
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iplt2_p1_c on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (ltrim(t3_1.c, 'A'::text) = t2_1.c)
+ Join Filter: (t2_1.b = t3_1.a)
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iplt2_p2_c on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: (ltrim(t3_2.c, 'A'::text) = t2_2.c)
+ Join Filter: (t2_2.b = t3_2.a)
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iplt2_p3_c on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 4) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 2) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 2 4) and (b 1) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 1 2) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Index Scan using iplt2_p1_c on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Index Scan using iplt1_p2_c on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Index Scan using iplt2_p2_c on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Index Scan using iplt2_p3_c on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Semi Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Index Only Scan using iplt2_p1_c on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Materialize
+ Output: t1_6.c
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t1_6
+ Output: t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Semi Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Index Only Scan using iplt2_p2_c on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Materialize
+ Output: t1_7.c
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t1_7
+ Output: t1_7.c
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Semi Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Index Only Scan using iplt2_p3_c on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Materialize
+ Output: t1_8.c
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t1_8
+ Output: t1_8.c
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 3) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 3 5) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- negative testcases
+--
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out
index f06cfa4..16e7f56 100644
--- a/src/test/regress/expected/rangefuncs.out
+++ b/src/test/regress/expected/rangefuncs.out
@@ -1,25 +1,26 @@
SELECT name, setting FROM pg_settings WHERE name LIKE 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
CREATE TABLE foo2(fooid int, f2 int);
INSERT INTO foo2 VALUES(1, 11);
INSERT INTO foo2 VALUES(2, 22);
INSERT INTO foo2 VALUES(1, 111);
CREATE FUNCTION foot(int) returns setof foo2 as 'SELECT * FROM foo2 WHERE fooid = $1 ORDER BY f2;' LANGUAGE SQL;
-- function with ORDINALITY
select * from foot(1) with ordinality as z(a,b,ord);
a | b | ord
---+-----+-----
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 8641769..5ad149d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -93,21 +93,21 @@ test: alter_generic alter_operator misc psql async dbsize misc_functions tsrf
# rules cannot run concurrently with any test that creates a view
test: rules psql_crosstab amutils
# run by itself so it can run parallel workers
test: select_parallel
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
# so keep this parallel group to at most 19 tests
# ----------
test: plancache limit plpgsql copy2 temp domain rangefuncs prepare without_oid conversion truncate alter_table sequence polymorphism rowtypes returning largeobject with xml
# event triggers cannot run concurrently with any test that runs DDL
test: event_trigger
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 835cf35..b4773b8 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -162,10 +162,11 @@ test: truncate
test: alter_table
test: sequence
test: polymorphism
test: rowtypes
test: returning
test: largeobject
test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..45e8a64
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,788 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a = 1 AND a = 2) t1 FULL JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- negative testcases
+--
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
On Thu, Sep 22, 2016 at 4:11 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
The patch is based on sources upto commit
commit 2a7f4f76434d82eb0d1b5f4f7051043e1dd3ee1a
Author: Heikki Linnakangas <heikki.linnakangas@iki.fi>
Date: Wed Sep 21 13:24:13 2016 +0300and Amit Langote's set of patches posted on 15th Sept. 2016 [1]
I have applied your patch on top of Amit patches posted on 15th Sept. 2016,
and tried to create some test cases on list and multi-level partition based
on test cases written for range partition.
I got some server crash and errors which I have mentioned as comment in
expected output file, which need to be updated once these issues will get
fix. also for these issue expected output is generated by creating same
query for non-partition table with same data.
Attached patch created on top to Ashutosh's patch posted on 22 Sept 2016.
Thanks & Regards,
Rajkumar Raghuwanshi
QMG, EnterpriseDB Corporation
Attachments:
partition_join_extra_testcases.patchinvalid/octet-stream; name=partition_join_extra_testcases.patchDownload
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
index 0eecade..16ed8e6 100644
--- a/src/test/regress/expected/partition_join.out
+++ b/src/test/regress/expected/partition_join.out
@@ -3993,6 +3993,416 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0
| | 525 | 0525
(16 rows)
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM (SELECT 50 phv, * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and t2.a + t2.b = t1.b + t1.a) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (50), prt1_l_p1_p1.a, prt1_l_p1_p1.b, prt1_l_p1_p1.c, (75), prt2_l_p1_p1.a, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Sort Key: (50), prt1_l_p1_p1.a, prt1_l_p1_p1.b, prt1_l_p1_p1.c, (75), prt2_l_p1_p1.a, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ -> Result
+ Output: (50), prt1_l_p1_p1.a, prt1_l_p1_p1.b, prt1_l_p1_p1.c, (75), prt2_l_p1_p1.a, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.b, prt1_l_p1_p1.c, prt2_l_p1_p1.a, prt2_l_p1_p1.b, prt2_l_p1_p1.c, (50), (75)
+ Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
+ Filter: (((50) = prt1_l_p1_p1.b) OR ((75) = prt2_l_p1_p1.b))
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.b, prt1_l_p1_p1.c, 50
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p1.a, prt2_l_p1_p1.b, prt2_l_p1_p1.c, (75)
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.a, prt2_l_p1_p1.b, prt2_l_p1_p1.c, 75
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.b, prt1_l_p1_p2.c, prt2_l_p1_p2.a, prt2_l_p1_p2.b, prt2_l_p1_p2.c, (50), (75)
+ Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
+ Filter: (((50) = prt1_l_p1_p2.b) OR ((75) = prt2_l_p1_p2.b))
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.b, prt1_l_p1_p2.c, 50
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p2.a, prt2_l_p1_p2.b, prt2_l_p1_p2.c, (75)
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.a, prt2_l_p1_p2.b, prt2_l_p1_p2.c, 75
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.b, prt1_l_p2_p1.c, prt2_l_p2_p1.a, prt2_l_p2_p1.b, prt2_l_p2_p1.c, (50), (75)
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ Filter: (((50) = prt1_l_p2_p1.b) OR ((75) = prt2_l_p2_p1.b))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.b, prt1_l_p2_p1.c, 50
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.a, prt2_l_p2_p1.b, prt2_l_p2_p1.c, (75)
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.a, prt2_l_p2_p1.b, prt2_l_p2_p1.c, 75
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.b, prt1_l_p2_p2.c, prt2_l_p2_p2.a, prt2_l_p2_p2.b, prt2_l_p2_p2.c, (50), (75)
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ Filter: (((50) = prt1_l_p2_p2.b) OR ((75) = prt2_l_p2_p2.b))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.b, prt1_l_p2_p2.c, 50
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.a, prt2_l_p2_p2.b, prt2_l_p2_p2.c, (75)
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.a, prt2_l_p2_p2.b, prt2_l_p2_p2.c, 75
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.b, prt1_l_p3_p1.c, prt2_l_p3_p1.a, prt2_l_p3_p1.b, prt2_l_p3_p1.c, (50), (75)
+ Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
+ Filter: (((50) = prt1_l_p3_p1.b) OR ((75) = prt2_l_p3_p1.b))
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.b, prt1_l_p3_p1.c, 50
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p1.a, prt2_l_p3_p1.b, prt2_l_p3_p1.c, (75)
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.a, prt2_l_p3_p1.b, prt2_l_p3_p1.c, 75
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.b, prt1_l_p3_p2.c, prt2_l_p3_p2.a, prt2_l_p3_p2.b, prt2_l_p3_p2.c, (50), (75)
+ Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
+ Filter: (((50) = prt1_l_p3_p2.b) OR ((75) = prt2_l_p3_p2.b))
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.b, prt1_l_p3_p2.c, 50
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p2.a, prt2_l_p3_p2.b, prt2_l_p3_p2.c, (75)
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.a, prt2_l_p3_p2.b, prt2_l_p3_p2.c, 75
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(78 rows)
+
+SELECT * FROM (SELECT 50 phv, * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and t2.a + t2.b = t1.b + t1.a) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ phv | a | b | c | phv | a | b | c
+-----+----+----+------+-----+----+----+------
+ 50 | 50 | 50 | 0050 | | | |
+ | | | | 75 | 75 | 75 | 0075
+(2 rows)
+
+SELECT * FROM (SELECT 50 phv, * FROM uprt1_l WHERE uprt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2_l WHERE uprt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and t2.a + t2.b = t1.b + t1.a) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+ phv | a | b | c | phv | a | b | c
+-----+----+----+------+-----+----+----+------
+ 50 | 50 | 50 | 0050 | | | |
+ | | | | 75 | 75 | 75 | 0075
+(2 rows)
+
+-- Join with pruned partitions from joining relations
+--Getting server crash, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+--Getting server crash, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+--Getting server crash, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+--Getting server crash, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a = 1 AND t1.a = 2;
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+--Getting server crash, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b;
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+--Getting server crash, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+--Getting server crash, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0075
+ | | 150 | 0150
+ | | 225 | 0225
+ | | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(8 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1_l t1 WHERE t1.a IN (SELECT t1.b FROM prt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_9.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_9.b
+ Sort Key: t1_9.b
+ -> Append
+ -> Seq Scan on public.prt2_l_p1 t1_9
+ Output: t1_9.b
+ Filter: ((t1_9.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1_p1 t1_10
+ Output: t1_10.b
+ Filter: ((t1_10.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p1_p2 t1_11
+ Output: t1_11.b
+ Filter: ((t1_11.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Merge Cond: (t1_3.a = t1_12.b)
+ -> Sort
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Sort Key: t1_3.a
+ -> Append
+ -> Seq Scan on public.prt1_l_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p1 t1_4
+ Output: t1_4.a, t1_4.b, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p2 t1_5
+ Output: t1_5.a, t1_5.b, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+ -> Sort
+ Output: t1_12.b
+ Sort Key: t1_12.b
+ -> Append
+ -> Seq Scan on public.prt2_l_p2 t1_12
+ Output: t1_12.b
+ Filter: ((t1_12.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2_p1 t1_13
+ Output: t1_13.b
+ Filter: ((t1_13.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p2_p2 t1_14
+ Output: t1_14.b
+ Filter: ((t1_14.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_6.a, t1_6.b, t1_6.c
+ Merge Cond: (t1_6.a = t1_15.b)
+ -> Sort
+ Output: t1_6.a, t1_6.b, t1_6.c
+ Sort Key: t1_6.a
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_6
+ Output: t1_6.a, t1_6.b, t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_7
+ Output: t1_7.a, t1_7.b, t1_7.c
+ Filter: ((t1_7.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_8
+ Output: t1_8.a, t1_8.b, t1_8.c
+ Filter: ((t1_8.a % 25) = 0)
+ -> Sort
+ Output: t1_15.b
+ Sort Key: t1_15.b
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t1_15
+ Output: t1_15.b
+ Filter: ((t1_15.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p1 t1_16
+ Output: t1_16.b
+ Filter: ((t1_16.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p2 t1_17
+ Output: t1_17.b
+ Filter: ((t1_17.b % 25) = 0)
+(89 rows)
+
+SELECT t1.* FROM prt1_l t1 WHERE t1.a IN (SELECT t1.b FROM prt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1_l t1 WHERE t1.a IN (SELECT t1.b FROM uprt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
--
-- tests for list partitioned tables.
--
@@ -4832,6 +5242,350 @@ SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b %
500 | 500 | 0010
(8 rows)
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: plt1.a, plt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2 t2 ON t1.a = t2.b;
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.plt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.plt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.plt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.plt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 FULL JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.plt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.plt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.plt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.plt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 FULL JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 WHERE a = 1 AND a = 2) t1 FULL JOIN uplt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.c, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ Sort Key: t1.a, t1.b, t1.c, t2.c, (LEAST(t1.c, t2.c, t3.c))
+ -> HashAggregate
+ Output: t1.a, t1.b, t1.c, t2.c, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ Group Key: t1.a, t1.b, t1.c, t2.c, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.c, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.c, t3.c, LEAST(t1.c, t2.c, t3.c)
+ Hash Cond: (t3.c = t2.c)
+ -> Seq Scan on public.plt2_p1 t3
+ Output: t3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_p1 t2
+ Output: t2.c
+ Filter: (t1.c = t2.c)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.c, t3_1.c, (LEAST(t1_1.c, t2_1.c, t3_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.c, t3_1.c, LEAST(t1_1.c, t2_1.c, t3_1.c)
+ Hash Cond: (t3_1.c = t2_1.c)
+ -> Seq Scan on public.plt2_p2 t3_1
+ Output: t3_1.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_p2 t2_1
+ Output: t2_1.c
+ Filter: (t1_1.c = t2_1.c)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.c, t3_2.c, (LEAST(t1_2.c, t2_2.c, t3_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.c, t3_2.c, LEAST(t1_2.c, t2_2.c, t3_2.c)
+ Hash Cond: (t3_2.c = t2_2.c)
+ -> Seq Scan on public.plt2_p3 t3_2
+ Output: t3_2.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_p3 t2_2
+ Output: t2_2.c
+ Filter: (t1_2.c = t2_2.c)
+(52 rows)
+
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2c | t3c | least
+-----+-----+------+------+------+-------
+ 0 | 0 | 0000 | 0000 | 0000 | 0000
+ 50 | 50 | 0001 | 0001 | 0001 | 0001
+ 100 | 100 | 0002 | 0002 | 0002 | 0002
+ 150 | 150 | 0003 | 0003 | 0003 | 0003
+ 200 | 200 | 0004 | 0004 | 0004 | 0004
+ 250 | 250 | 0005 | 0005 | 0005 | 0005
+ 300 | 300 | 0006 | 0006 | 0006 | 0006
+ 350 | 350 | 0007 | 0007 | 0007 | 0007
+ 400 | 400 | 0008 | 0008 | 0008 | 0008
+ 450 | 450 | 0009 | 0009 | 0009 | 0009
+ 500 | 500 | 0010 | 0010 | 0010 | 0010
+ 550 | 550 | 0011 | 0011 | 0011 | 0011
+(12 rows)
+
+SELECT distinct * FROM uplt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM uplt1 t2 JOIN uplt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+ a | b | c | t2c | t3c | least
+-----+-----+------+------+------+-------
+ 0 | 0 | 0000 | 0000 | 0000 | 0000
+ 50 | 50 | 0001 | 0001 | 0001 | 0001
+ 100 | 100 | 0002 | 0002 | 0002 | 0002
+ 150 | 150 | 0003 | 0003 | 0003 | 0003
+ 200 | 200 | 0004 | 0004 | 0004 | 0004
+ 250 | 250 | 0005 | 0005 | 0005 | 0005
+ 300 | 300 | 0006 | 0006 | 0006 | 0006
+ 350 | 350 | 0007 | 0007 | 0007 | 0007
+ 400 | 400 | 0008 | 0008 | 0008 | 0008
+ 450 | 450 | 0009 | 0009 | 0009 | 0009
+ 500 | 500 | 0010 | 0010 | 0010 | 0010
+ 550 | 550 | 0011 | 0011 | 0011 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Unique
+ Output: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ Sort Key: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Append
+ -> Seq Scan on public.plt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.plt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.plt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.plt1_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.c, LEAST(t1.c, t2.c, t3.c)
+ Hash Cond: (t3.c = t2.c)
+ -> Seq Scan on public.plt2_p1 t3
+ Output: t3.c
+ -> Hash
+ Output: t2.a, t2.c
+ -> Seq Scan on public.plt1_p1 t2
+ Output: t2.a, t2.c
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_1.c, LEAST(t1.c, t2_1.c, t3_1.c)
+ Hash Cond: (t3_1.c = t2_1.c)
+ -> Seq Scan on public.plt2_p2 t3_1
+ Output: t3_1.c
+ -> Hash
+ Output: t2_1.a, t2_1.c
+ -> Seq Scan on public.plt1_p2 t2_1
+ Output: t2_1.a, t2_1.c
+ Filter: (t1.b = t2_1.a)
+ -> Hash Join
+ Output: t2_2.a, t3_2.c, LEAST(t1.c, t2_2.c, t3_2.c)
+ Hash Cond: (t3_2.c = t2_2.c)
+ -> Seq Scan on public.plt2_p3 t3_2
+ Output: t3_2.c
+ -> Hash
+ Output: t2_2.a, t2_2.c
+ -> Seq Scan on public.plt1_p3 t2_2
+ Output: t2_2.a, t2_2.c
+ Filter: (t1.b = t2_2.a)
+(51 rows)
+
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3c | least
+-----+-----+------+-----+------+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0000
+ 50 | 50 | 0001 | 50 | 0001 | 0001
+ 100 | 100 | 0002 | 100 | 0002 | 0002
+ 150 | 150 | 0003 | 150 | 0003 | 0003
+ 200 | 200 | 0004 | 200 | 0004 | 0004
+ 250 | 250 | 0005 | 250 | 0005 | 0005
+ 300 | 300 | 0006 | 300 | 0006 | 0006
+ 350 | 350 | 0007 | 350 | 0007 | 0007
+ 400 | 400 | 0008 | 400 | 0008 | 0008
+ 450 | 450 | 0009 | 450 | 0009 | 0009
+ 500 | 500 | 0010 | 500 | 0010 | 0010
+ 550 | 550 | 0011 | 550 | 0011 | 0011
+(12 rows)
+
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3c | least
+-----+-----+------+-----+------+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0000
+ 50 | 50 | 0001 | 50 | 0001 | 0001
+ 100 | 100 | 0002 | 100 | 0002 | 0002
+ 150 | 150 | 0003 | 150 | 0003 | 0003
+ 200 | 200 | 0004 | 200 | 0004 | 0004
+ 250 | 250 | 0005 | 250 | 0005 | 0005
+ 300 | 300 | 0006 | 300 | 0006 | 0006
+ 350 | 350 | 0007 | 350 | 0007 | 0007
+ 400 | 400 | 0008 | 400 | 0008 | 0008
+ 450 | 450 | 0009 | 450 | 0009 | 0009
+ 500 | 500 | 0010 | 500 | 0010 | 0010
+ 550 | 550 | 0011 | 550 | 0011 | 0011
+(12 rows)
+
--
-- list partitioned by expression
--
@@ -5998,6 +6752,88 @@ SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN
550 | 550 | 0011
(12 rows)
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, ltrim(t3.c,'A'), t3.phv FROM ((SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c)) FULL JOIN (SELECT '0002'::text phv, * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.c = ltrim(t3.c,'A')) WHERE t1.a = t1.phv OR t2.b = t2.phv OR ltrim(t3.c,'A') = t3.phv ORDER BY t1.a, t2.b, ltrim(t3.c,'A');
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, (50), plt2_p1.b, (75), (ltrim(plt1_e.c, 'A'::text)), ('0002'::text)
+ Sort Key: plt1_p1.a, plt2_p1.b, (ltrim(plt1_e.c, 'A'::text))
+ -> Hash Full Join
+ Output: plt1_p1.a, (50), plt2_p1.b, (75), ltrim(plt1_e.c, 'A'::text), ('0002'::text)
+ Hash Cond: (plt1_p1.c = ltrim(plt1_e.c, 'A'::text))
+ Filter: ((plt1_p1.a = (50)) OR (plt2_p1.b = (75)) OR (ltrim(plt1_e.c, 'A'::text) = ('0002'::text)))
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, (50), (75)
+ Hash Cond: (plt1_p1.c = plt2_p1.c)
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c, 50
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c, (75)
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c, 75
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, (50), (75)
+ Hash Cond: (plt1_p2.c = plt2_p2.c)
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c, 50
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c, (75)
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c, 75
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, (50), (75)
+ Hash Cond: (plt1_p3.c = plt2_p3.c)
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c, 50
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c, (75)
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c, 75
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e.c, ('0002'::text)
+ -> Append
+ -> Seq Scan on public.plt1_e
+ Output: plt1_e.c, '0002'::text
+ Filter: ((plt1_e.a % 25) = 0)
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.c, '0002'::text
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.c, '0002'::text
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.c, '0002'::text
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(56 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, ltrim(t3.c,'A'), t3.phv FROM ((SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c)) FULL JOIN (SELECT '0002'::text phv, * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.c = ltrim(t3.c,'A')) WHERE t1.a = t1.phv OR t2.b = t2.phv OR ltrim(t3.c,'A') = t3.phv ORDER BY t1.a, t2.b, ltrim(t3.c,'A');
+NOTICE: join between relations (b 6) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 6 7) and (b 8) is considered for partition-wise join.
+ a | phv | b | phv | ltrim | phv
+-----+-----+----+-----+-------+------
+ 50 | 50 | 75 | 75 | 0001 | 0002
+ 100 | 50 | | | 0002 | 0002
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, ltrim(t3.c,'A'), t3.phv FROM ((SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c)) FULL JOIN (SELECT '0002'::text phv, * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.c = ltrim(t3.c,'A')) WHERE t1.a = t1.phv OR t2.b = t2.phv OR ltrim(t3.c,'A') = t3.phv ORDER BY t1.a, t2.b, ltrim(t3.c,'A');
+ a | phv | b | phv | ltrim | phv
+-----+-----+----+-----+-------+------
+ 50 | 50 | 75 | 75 | 0001 | 0002
+ 100 | 50 | | | 0002 | 0002
+(2 rows)
+
-- test merge join with and without index scan
CREATE INDEX iplt1_c on plt1(c);
CREATE INDEX iplt1_p1_c on plt1_p1(c);
@@ -6781,9 +7617,1510 @@ SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN
550 | 550 | 0011
(12 rows)
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Unique
+ Output: t1.a, t1.b, t1.c, t2.c, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Sort
+ Output: t1.a, t1.b, t1.c, t2.c, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ Sort Key: t1.a, t1.b, t1.c, t2.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.c, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Append
+ -> Index Scan using iplt1_c on public.plt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.c, t3.c, LEAST(t1.c, t2.c, t3.c)
+ Merge Cond: (t2.c = t3.c)
+ -> Index Only Scan using iplt1_p1_c on public.plt1_p1 t2
+ Output: t2.c
+ Index Cond: (t2.c = t1.c)
+ -> Materialize
+ Output: t3.c
+ -> Index Only Scan using iplt2_p1_c on public.plt2_p1 t3
+ Output: t3.c
+ -> Merge Join
+ Output: t2_1.c, t3_1.c, LEAST(t1.c, t2_1.c, t3_1.c)
+ Merge Cond: (t2_1.c = t3_1.c)
+ -> Index Only Scan using iplt1_p2_c on public.plt1_p2 t2_1
+ Output: t2_1.c
+ Index Cond: (t2_1.c = t1.c)
+ -> Materialize
+ Output: t3_1.c
+ -> Index Only Scan using iplt2_p2_c on public.plt2_p2 t3_1
+ Output: t3_1.c
+ -> Merge Join
+ Output: t2_2.c, t3_2.c, LEAST(t1.c, t2_2.c, t3_2.c)
+ Merge Cond: (t2_2.c = t3_2.c)
+ -> Index Only Scan using iplt1_p3_c on public.plt1_p3 t2_2
+ Output: t2_2.c
+ Index Cond: (t2_2.c = t1.c)
+ -> Materialize
+ Output: t3_2.c
+ -> Index Only Scan using iplt2_p3_c on public.plt2_p3 t3_2
+ Output: t3_2.c
+(51 rows)
+
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 1) and (b 4 5) is considered for partition-wise join.
+ a | b | c | t2c | t3c | least
+-----+-----+------+------+------+-------
+ 0 | 0 | 0000 | 0000 | 0000 | 0000
+ 50 | 50 | 0001 | 0001 | 0001 | 0001
+ 100 | 100 | 0002 | 0002 | 0002 | 0002
+ 150 | 150 | 0003 | 0003 | 0003 | 0003
+ 200 | 200 | 0004 | 0004 | 0004 | 0004
+ 250 | 250 | 0005 | 0005 | 0005 | 0005
+ 300 | 300 | 0006 | 0006 | 0006 | 0006
+ 350 | 350 | 0007 | 0007 | 0007 | 0007
+ 400 | 400 | 0008 | 0008 | 0008 | 0008
+ 450 | 450 | 0009 | 0009 | 0009 | 0009
+ 500 | 500 | 0010 | 0010 | 0010 | 0010
+ 550 | 550 | 0011 | 0011 | 0011 | 0011
+(12 rows)
+
+SELECT distinct * FROM uplt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM uplt1 t2 JOIN uplt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+ a | b | c | t2c | t3c | least
+-----+-----+------+------+------+-------
+ 0 | 0 | 0000 | 0000 | 0000 | 0000
+ 50 | 50 | 0001 | 0001 | 0001 | 0001
+ 100 | 100 | 0002 | 0002 | 0002 | 0002
+ 150 | 150 | 0003 | 0003 | 0003 | 0003
+ 200 | 200 | 0004 | 0004 | 0004 | 0004
+ 250 | 250 | 0005 | 0005 | 0005 | 0005
+ 300 | 300 | 0006 | 0006 | 0006 | 0006
+ 350 | 350 | 0007 | 0007 | 0007 | 0007
+ 400 | 400 | 0008 | 0008 | 0008 | 0008
+ 450 | 450 | 0009 | 0009 | 0009 | 0009
+ 500 | 500 | 0010 | 0010 | 0010 | 0010
+ 550 | 550 | 0011 | 0011 | 0011 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Unique
+ Output: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ Sort Key: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.c, (LEAST(t1.c, t2.c, t3.c))
+ -> Append
+ -> Seq Scan on public.plt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.plt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.plt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.plt1_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.c, LEAST(t1.c, t2.c, t3.c)
+ Merge Cond: (t2.c = t3.c)
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t2
+ Output: t2.a, t2.c
+ Filter: (t1.b = t2.a)
+ -> Index Only Scan using iplt2_p1_c on public.plt2_p1 t3
+ Output: t3.c
+ -> Merge Join
+ Output: t2_1.a, t3_1.c, LEAST(t1.c, t2_1.c, t3_1.c)
+ Merge Cond: (t2_1.c = t3_1.c)
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t2_1
+ Output: t2_1.a, t2_1.c
+ Filter: (t1.b = t2_1.a)
+ -> Index Only Scan using iplt2_p2_c on public.plt2_p2 t3_1
+ Output: t3_1.c
+ -> Merge Join
+ Output: t2_2.a, t3_2.c, LEAST(t1.c, t2_2.c, t3_2.c)
+ Merge Cond: (t2_2.c = t3_2.c)
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t2_2
+ Output: t2_2.a, t2_2.c
+ Filter: (t1.b = t2_2.a)
+ -> Index Only Scan using iplt2_p3_c on public.plt2_p3 t3_2
+ Output: t3_2.c
+(45 rows)
+
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+ a | b | c | t2a | t3c | least
+-----+-----+------+-----+------+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0000
+ 50 | 50 | 0001 | 50 | 0001 | 0001
+ 100 | 100 | 0002 | 100 | 0002 | 0002
+ 150 | 150 | 0003 | 150 | 0003 | 0003
+ 200 | 200 | 0004 | 200 | 0004 | 0004
+ 250 | 250 | 0005 | 250 | 0005 | 0005
+ 300 | 300 | 0006 | 300 | 0006 | 0006
+ 350 | 350 | 0007 | 350 | 0007 | 0007
+ 400 | 400 | 0008 | 400 | 0008 | 0008
+ 450 | 450 | 0009 | 450 | 0009 | 0009
+ 500 | 500 | 0010 | 500 | 0010 | 0010
+ 550 | 550 | 0011 | 550 | 0011 | 0011
+(12 rows)
+
+SELECT distinct * FROM uplt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM uplt1 t2 JOIN uplt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+ a | b | c | t2a | t3c | least
+-----+-----+------+-----+------+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0000
+ 50 | 50 | 0001 | 50 | 0001 | 0001
+ 100 | 100 | 0002 | 100 | 0002 | 0002
+ 150 | 150 | 0003 | 150 | 0003 | 0003
+ 200 | 200 | 0004 | 200 | 0004 | 0004
+ 250 | 250 | 0005 | 250 | 0005 | 0005
+ 300 | 300 | 0006 | 300 | 0006 | 0006
+ 350 | 350 | 0007 | 350 | 0007 | 0007
+ 400 | 400 | 0008 | 400 | 0008 | 0008
+ 450 | 450 | 0009 | 450 | 0009 | 0009
+ 500 | 500 | 0010 | 500 | 0010 | 0010
+ 550 | 550 | 0011 | 550 | 0011 | 0011
+(12 rows)
+
RESET enable_hashjoin;
RESET enable_nestloop;
RESET enable_seqscan;
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE plt1_l (a int, b int, c varchar) PARTITION BY LIST(c);
+CREATE TABLE plt1_l_p1 PARTITION OF plt1_l FOR VALUES IN ('0000', '0003', '0004', '0010') PARTITION BY LIST (c);
+CREATE TABLE plt1_l_p1_p1 PARTITION OF plt1_l_p1 FOR VALUES IN ('0000', '0003');
+CREATE TABLE plt1_l_p1_p2 PARTITION OF plt1_l_p1 FOR VALUES IN ('0004', '0010');
+CREATE TABLE plt1_l_p2 PARTITION OF plt1_l FOR VALUES IN ('0001', '0005', '0002', '0009') PARTITION BY LIST (c);
+CREATE TABLE plt1_l_p2_p1 PARTITION OF plt1_l_p2 FOR VALUES IN ('0001', '0005');
+CREATE TABLE plt1_l_p2_p2 PARTITION OF plt1_l_p2 FOR VALUES IN ('0002', '0009');
+CREATE TABLE plt1_l_p3 PARTITION OF plt1_l FOR VALUES IN ('0006', '0007', '0008', '0011') PARTITION BY LIST (ltrim(c,'A'));
+CREATE TABLE plt1_l_p3_p1 PARTITION OF plt1_l_p3 FOR VALUES IN ('0006', '0007');
+CREATE TABLE plt1_l_p3_p2 PARTITION OF plt1_l_p3 FOR VALUES IN ('0008', '0011');
+INSERT INTO plt1_l SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_l;
+ANALYZE plt1_l_p1;
+ANALYZE plt1_l_p1_p1;
+ANALYZE plt1_l_p1_p2;
+ANALYZE plt1_l_p2;
+ANALYZE plt1_l_p2_p1;
+ANALYZE plt1_l_p2_p2;
+ANALYZE plt1_l_p3;
+ANALYZE plt1_l_p3_p1;
+ANALYZE plt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_l AS SELECT * FROM plt1_l;
+CREATE TABLE plt2_l (a int, b int, c varchar) PARTITION BY LIST(c);
+CREATE TABLE plt2_l_p1 PARTITION OF plt2_l FOR VALUES IN ('0000', '0003', '0004', '0010') PARTITION BY LIST (c);
+CREATE TABLE plt2_l_p1_p1 PARTITION OF plt2_l_p1 FOR VALUES IN ('0000', '0003');
+CREATE TABLE plt2_l_p1_p2 PARTITION OF plt2_l_p1 FOR VALUES IN ('0004', '0010');
+CREATE TABLE plt2_l_p2 PARTITION OF plt2_l FOR VALUES IN ('0001', '0005', '0002', '0009') PARTITION BY LIST (c);
+CREATE TABLE plt2_l_p2_p1 PARTITION OF plt2_l_p2 FOR VALUES IN ('0001', '0005');
+CREATE TABLE plt2_l_p2_p2 PARTITION OF plt2_l_p2 FOR VALUES IN ('0002', '0009');
+CREATE TABLE plt2_l_p3 PARTITION OF plt2_l FOR VALUES IN ('0006', '0007', '0008', '0011') PARTITION BY LIST (ltrim(c,'A'));
+CREATE TABLE plt2_l_p3_p1 PARTITION OF plt2_l_p3 FOR VALUES IN ('0006', '0007');
+CREATE TABLE plt2_l_p3_p2 PARTITION OF plt2_l_p3 FOR VALUES IN ('0008', '0011');
+INSERT INTO plt2_l SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_l;
+ANALYZE plt2_l_p1;
+ANALYZE plt2_l_p1_p1;
+ANALYZE plt2_l_p1_p2;
+ANALYZE plt2_l_p2;
+ANALYZE plt2_l_p2_p1;
+ANALYZE plt2_l_p2_p2;
+ANALYZE plt2_l_p3;
+ANALYZE plt2_l_p3_p1;
+ANALYZE plt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_l AS SELECT * FROM plt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND (ltrim((t2.c)::text, 'A'::text) = ltrim((t1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.plt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND (ltrim((t2_1.c)::text, 'A'::text) = ltrim((t1_1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.plt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND (ltrim((t2_2.c)::text, 'A'::text) = ltrim((t1_2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.plt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND (ltrim((t2_3.c)::text, 'A'::text) = ltrim((t1_3.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.plt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND (ltrim((t2_4.c)::text, 'A'::text) = ltrim((t1_4.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.plt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND (ltrim((t2_5.c)::text, 'A'::text) = ltrim((t1_5.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.plt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1, uplt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND (ltrim((t2.c)::text, 'A'::text) = ltrim((t1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.plt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND (ltrim((t2_1.c)::text, 'A'::text) = ltrim((t1_1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.plt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND (ltrim((t2_2.c)::text, 'A'::text) = ltrim((t1_2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.plt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND (ltrim((t2_3.c)::text, 'A'::text) = ltrim((t1_3.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.plt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND (ltrim((t2_4.c)::text, 'A'::text) = ltrim((t1_4.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.plt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND (ltrim((t2_5.c)::text, 'A'::text) = ltrim((t1_5.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.plt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1 LEFT JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND (ltrim((t2.c)::text, 'A'::text) = ltrim((t1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.plt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND (ltrim((t2_1.c)::text, 'A'::text) = ltrim((t1_1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.plt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND (ltrim((t2_2.c)::text, 'A'::text) = ltrim((t1_2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.plt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND (ltrim((t2_3.c)::text, 'A'::text) = ltrim((t1_3.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.plt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND (ltrim((t2_4.c)::text, 'A'::text) = ltrim((t1_4.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.plt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND (ltrim((t2_5.c)::text, 'A'::text) = ltrim((t1_5.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.plt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+NOTICE: join between relations (b 13) and (b 26) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1 RIGHT JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Sort Key: plt1_l_p1_p1.a, plt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Hash Cond: ((plt1_l_p1_p1.a = plt2_l_p1_p1.b) AND (plt1_l_p1_p1.b = plt2_l_p1_p1.a) AND ((plt1_l_p1_p1.c)::text = (plt2_l_p1_p1.c)::text) AND (ltrim((plt1_l_p1_p1.c)::text, 'A'::text) = ltrim((plt2_l_p1_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p1
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt1_l_p1_p1.b
+ Filter: ((plt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt2_l_p1_p1.a
+ -> Seq Scan on public.plt2_l_p1_p1
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt2_l_p1_p1.a
+ Filter: ((plt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt2_l_p1_p2.b, plt2_l_p1_p2.c
+ Hash Cond: ((plt1_l_p1_p2.a = plt2_l_p1_p2.b) AND (plt1_l_p1_p2.b = plt2_l_p1_p2.a) AND ((plt1_l_p1_p2.c)::text = (plt2_l_p1_p2.c)::text) AND (ltrim((plt1_l_p1_p2.c)::text, 'A'::text) = ltrim((plt2_l_p1_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p2
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt1_l_p1_p2.b
+ Filter: ((plt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt2_l_p1_p2.a
+ -> Seq Scan on public.plt2_l_p1_p2
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt2_l_p1_p2.a
+ Filter: ((plt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.c, plt2_l_p2_p1.b, plt2_l_p2_p1.c
+ Hash Cond: ((plt1_l_p2_p1.a = plt2_l_p2_p1.b) AND (plt1_l_p2_p1.b = plt2_l_p2_p1.a) AND ((plt1_l_p2_p1.c)::text = (plt2_l_p2_p1.c)::text) AND (ltrim((plt1_l_p2_p1.c)::text, 'A'::text) = ltrim((plt2_l_p2_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p2_p1
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.c, plt1_l_p2_p1.b
+ Filter: ((plt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ -> Seq Scan on public.plt2_l_p2_p1
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ Filter: ((plt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt2_l_p2_p2.b, plt2_l_p2_p2.c
+ Hash Cond: ((plt1_l_p2_p2.a = plt2_l_p2_p2.b) AND (plt1_l_p2_p2.b = plt2_l_p2_p2.a) AND ((plt1_l_p2_p2.c)::text = (plt2_l_p2_p2.c)::text) AND (ltrim((plt1_l_p2_p2.c)::text, 'A'::text) = ltrim((plt2_l_p2_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p2_p2
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt1_l_p2_p2.b
+ Filter: ((plt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt2_l_p2_p2.a
+ -> Seq Scan on public.plt2_l_p2_p2
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt2_l_p2_p2.a
+ Filter: ((plt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt2_l_p3_p1.b, plt2_l_p3_p1.c
+ Hash Cond: ((plt1_l_p3_p1.a = plt2_l_p3_p1.b) AND (plt1_l_p3_p1.b = plt2_l_p3_p1.a) AND ((plt1_l_p3_p1.c)::text = (plt2_l_p3_p1.c)::text) AND (ltrim((plt1_l_p3_p1.c)::text, 'A'::text) = ltrim((plt2_l_p3_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p3_p1
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt1_l_p3_p1.b
+ Filter: ((plt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt2_l_p3_p1.a
+ -> Seq Scan on public.plt2_l_p3_p1
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt2_l_p3_p1.a
+ Filter: ((plt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt2_l_p3_p2.b, plt2_l_p3_p2.c
+ Hash Cond: ((plt1_l_p3_p2.a = plt2_l_p3_p2.b) AND (plt1_l_p3_p2.b = plt2_l_p3_p2.a) AND ((plt1_l_p3_p2.c)::text = (plt2_l_p3_p2.c)::text) AND (ltrim((plt1_l_p3_p2.c)::text, 'A'::text) = ltrim((plt2_l_p3_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p3_p2
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt1_l_p3_p2.b
+ Filter: ((plt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt2_l_p3_p2.a
+ -> Seq Scan on public.plt2_l_p3_p2
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt2_l_p3_p2.a
+ Filter: ((plt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A')) ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+-- lateral reference
+--Getting could not devise a query plan error, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0000
+ 50 | 50 | 0001 | | | | |
+ 100 | 100 | 0002 | | | | |
+ 150 | 150 | 0003 | 150 | 0003 | 150 | 150 | 0003
+ 200 | 200 | 0004 | | | | |
+ 250 | 250 | 0005 | | | | |
+ 300 | 300 | 0006 | 300 | 0006 | 300 | 300 | 0006
+ 350 | 350 | 0007 | | | | |
+ 400 | 400 | 0008 | | | | |
+ 450 | 450 | 0009 | 450 | 0009 | 450 | 450 | 0009
+ 500 | 500 | 0010 | | | | |
+ 550 | 550 | 0011 | | | | |
+(12 rows)
+
+SELECT * FROM uplt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM uplt1_l t2 JOIN uplt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0000
+ 50 | 50 | 0001 | | | | |
+ 100 | 100 | 0002 | | | | |
+ 150 | 150 | 0003 | 150 | 0003 | 150 | 150 | 0003
+ 200 | 200 | 0004 | | | | |
+ 250 | 250 | 0005 | | | | |
+ 300 | 300 | 0006 | 300 | 0006 | 300 | 300 | 0006
+ 350 | 350 | 0007 | | | | |
+ 400 | 400 | 0008 | | | | |
+ 450 | 450 | 0009 | 450 | 0009 | 450 | 450 | 0009
+ 500 | 500 | 0010 | | | | |
+ 550 | 550 | 0011 | | | | |
+(12 rows)
+
+--Getting could not devise a query plan error, need to be fix to get query output
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0000
+ 50 | 50 | 0001 | | | | |
+ 100 | 100 | 0002 | | | | |
+ 150 | 150 | 0003 | 150 | 0003 | 150 | 150 | 0003
+ 200 | 200 | 0004 | | | | |
+ 250 | 250 | 0005 | | | | |
+ 300 | 300 | 0006 | 300 | 0006 | 300 | 300 | 0006
+ 350 | 350 | 0007 | | | | |
+ 400 | 400 | 0008 | | | | |
+ 450 | 450 | 0009 | 450 | 0009 | 450 | 450 | 0009
+ 500 | 500 | 0010 | | | | |
+ 550 | 550 | 0011 | | | | |
+(12 rows)
+
+SELECT * FROM uplt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM uplt1_l t2 JOIN uplt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0000
+ 50 | 50 | 0001 | | | | |
+ 100 | 100 | 0002 | | | | |
+ 150 | 150 | 0003 | 150 | 0003 | 150 | 150 | 0003
+ 200 | 200 | 0004 | | | | |
+ 250 | 250 | 0005 | | | | |
+ 300 | 300 | 0006 | 300 | 0006 | 300 | 300 | 0006
+ 350 | 350 | 0007 | | | | |
+ 400 | 400 | 0008 | | | | |
+ 450 | 450 | 0009 | 450 | 0009 | 450 | 450 | 0009
+ 500 | 500 | 0010 | | | | |
+ 550 | 550 | 0011 | | | | |
+(12 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM (SELECT 50 phv, * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and ltrim(t2.c,'A') = ltrim(t1.c,'A')) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (50), plt1_l_p1_p1.a, plt1_l_p1_p1.b, plt1_l_p1_p1.c, (75), plt2_l_p1_p1.a, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Sort Key: (50), plt1_l_p1_p1.a, plt1_l_p1_p1.b, plt1_l_p1_p1.c, (75), plt2_l_p1_p1.a, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ -> Result
+ Output: (50), plt1_l_p1_p1.a, plt1_l_p1_p1.b, plt1_l_p1_p1.c, (75), plt2_l_p1_p1.a, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.b, plt1_l_p1_p1.c, plt2_l_p1_p1.a, plt2_l_p1_p1.b, plt2_l_p1_p1.c, (50), (75)
+ Hash Cond: ((plt1_l_p1_p1.a = plt2_l_p1_p1.b) AND (plt1_l_p1_p1.b = plt2_l_p1_p1.a) AND ((plt1_l_p1_p1.c)::text = (plt2_l_p1_p1.c)::text) AND (ltrim((plt1_l_p1_p1.c)::text, 'A'::text) = ltrim((plt2_l_p1_p1.c)::text, 'A'::text)))
+ Filter: (((50) = plt1_l_p1_p1.b) OR ((75) = plt2_l_p1_p1.b))
+ -> Seq Scan on public.plt1_l_p1_p1
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.b, plt1_l_p1_p1.c, 50
+ Filter: ((plt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p1_p1.a, plt2_l_p1_p1.b, plt2_l_p1_p1.c, (75)
+ -> Seq Scan on public.plt2_l_p1_p1
+ Output: plt2_l_p1_p1.a, plt2_l_p1_p1.b, plt2_l_p1_p1.c, 75
+ Filter: ((plt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.b, plt1_l_p1_p2.c, plt2_l_p1_p2.a, plt2_l_p1_p2.b, plt2_l_p1_p2.c, (50), (75)
+ Hash Cond: ((plt1_l_p1_p2.a = plt2_l_p1_p2.b) AND (plt1_l_p1_p2.b = plt2_l_p1_p2.a) AND ((plt1_l_p1_p2.c)::text = (plt2_l_p1_p2.c)::text) AND (ltrim((plt1_l_p1_p2.c)::text, 'A'::text) = ltrim((plt2_l_p1_p2.c)::text, 'A'::text)))
+ Filter: (((50) = plt1_l_p1_p2.b) OR ((75) = plt2_l_p1_p2.b))
+ -> Seq Scan on public.plt1_l_p1_p2
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.b, plt1_l_p1_p2.c, 50
+ Filter: ((plt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p1_p2.a, plt2_l_p1_p2.b, plt2_l_p1_p2.c, (75)
+ -> Seq Scan on public.plt2_l_p1_p2
+ Output: plt2_l_p1_p2.a, plt2_l_p1_p2.b, plt2_l_p1_p2.c, 75
+ Filter: ((plt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.b, plt1_l_p2_p1.c, plt2_l_p2_p1.a, plt2_l_p2_p1.b, plt2_l_p2_p1.c, (50), (75)
+ Hash Cond: ((plt1_l_p2_p1.a = plt2_l_p2_p1.b) AND (plt1_l_p2_p1.b = plt2_l_p2_p1.a) AND ((plt1_l_p2_p1.c)::text = (plt2_l_p2_p1.c)::text) AND (ltrim((plt1_l_p2_p1.c)::text, 'A'::text) = ltrim((plt2_l_p2_p1.c)::text, 'A'::text)))
+ Filter: (((50) = plt1_l_p2_p1.b) OR ((75) = plt2_l_p2_p1.b))
+ -> Seq Scan on public.plt1_l_p2_p1
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.b, plt1_l_p2_p1.c, 50
+ Filter: ((plt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p2_p1.a, plt2_l_p2_p1.b, plt2_l_p2_p1.c, (75)
+ -> Seq Scan on public.plt2_l_p2_p1
+ Output: plt2_l_p2_p1.a, plt2_l_p2_p1.b, plt2_l_p2_p1.c, 75
+ Filter: ((plt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.b, plt1_l_p2_p2.c, plt2_l_p2_p2.a, plt2_l_p2_p2.b, plt2_l_p2_p2.c, (50), (75)
+ Hash Cond: ((plt1_l_p2_p2.a = plt2_l_p2_p2.b) AND (plt1_l_p2_p2.b = plt2_l_p2_p2.a) AND ((plt1_l_p2_p2.c)::text = (plt2_l_p2_p2.c)::text) AND (ltrim((plt1_l_p2_p2.c)::text, 'A'::text) = ltrim((plt2_l_p2_p2.c)::text, 'A'::text)))
+ Filter: (((50) = plt1_l_p2_p2.b) OR ((75) = plt2_l_p2_p2.b))
+ -> Seq Scan on public.plt1_l_p2_p2
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.b, plt1_l_p2_p2.c, 50
+ Filter: ((plt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p2_p2.a, plt2_l_p2_p2.b, plt2_l_p2_p2.c, (75)
+ -> Seq Scan on public.plt2_l_p2_p2
+ Output: plt2_l_p2_p2.a, plt2_l_p2_p2.b, plt2_l_p2_p2.c, 75
+ Filter: ((plt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.b, plt1_l_p3_p1.c, plt2_l_p3_p1.a, plt2_l_p3_p1.b, plt2_l_p3_p1.c, (50), (75)
+ Hash Cond: ((plt1_l_p3_p1.a = plt2_l_p3_p1.b) AND (plt1_l_p3_p1.b = plt2_l_p3_p1.a) AND ((plt1_l_p3_p1.c)::text = (plt2_l_p3_p1.c)::text) AND (ltrim((plt1_l_p3_p1.c)::text, 'A'::text) = ltrim((plt2_l_p3_p1.c)::text, 'A'::text)))
+ Filter: (((50) = plt1_l_p3_p1.b) OR ((75) = plt2_l_p3_p1.b))
+ -> Seq Scan on public.plt1_l_p3_p1
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.b, plt1_l_p3_p1.c, 50
+ Filter: ((plt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p3_p1.a, plt2_l_p3_p1.b, plt2_l_p3_p1.c, (75)
+ -> Seq Scan on public.plt2_l_p3_p1
+ Output: plt2_l_p3_p1.a, plt2_l_p3_p1.b, plt2_l_p3_p1.c, 75
+ Filter: ((plt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.b, plt1_l_p3_p2.c, plt2_l_p3_p2.a, plt2_l_p3_p2.b, plt2_l_p3_p2.c, (50), (75)
+ Hash Cond: ((plt1_l_p3_p2.a = plt2_l_p3_p2.b) AND (plt1_l_p3_p2.b = plt2_l_p3_p2.a) AND ((plt1_l_p3_p2.c)::text = (plt2_l_p3_p2.c)::text) AND (ltrim((plt1_l_p3_p2.c)::text, 'A'::text) = ltrim((plt2_l_p3_p2.c)::text, 'A'::text)))
+ Filter: (((50) = plt1_l_p3_p2.b) OR ((75) = plt2_l_p3_p2.b))
+ -> Seq Scan on public.plt1_l_p3_p2
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.b, plt1_l_p3_p2.c, 50
+ Filter: ((plt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_l_p3_p2.a, plt2_l_p3_p2.b, plt2_l_p3_p2.c, (75)
+ -> Seq Scan on public.plt2_l_p3_p2
+ Output: plt2_l_p3_p2.a, plt2_l_p3_p2.b, plt2_l_p3_p2.c, 75
+ Filter: ((plt2_l_p3_p2.b % 25) = 0)
+(78 rows)
+
+SELECT * FROM (SELECT 50 phv, * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and ltrim(t2.c,'A') = ltrim(t1.c,'A')) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ phv | a | b | c | phv | a | b | c
+-----+----+----+------+-----+----+----+------
+ 50 | 50 | 50 | 0001 | | | |
+ | | | | 75 | 75 | 75 | 0001
+(2 rows)
+
+SELECT * FROM (SELECT 50 phv, * FROM uplt1_l WHERE uplt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2_l WHERE uplt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and ltrim(t2.c,'A') = ltrim(t1.c,'A')) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+ phv | a | b | c | phv | a | b | c
+-----+----+----+------+-----+----+----+------
+ 50 | 50 | 50 | 0001 | | | |
+ | | | | 75 | 75 | 75 | 0001
+(2 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop
+ Output: t1.a, t1.c, t2.b, t2.c
+ Join Filter: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND (ltrim((t1.c)::text, 'A'::text) = ltrim((t2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+ -> Seq Scan on public.plt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: (t2.b > 250)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND (ltrim((t2_1.c)::text, 'A'::text) = ltrim((t1_1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: (t2_1.b > 250)
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.plt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a < 450) AND ((t1_1.a % 25) = 0))
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND (ltrim((t2_2.c)::text, 'A'::text) = ltrim((t1_2.c)::text, 'A'::text)))
+ -> Append
+ -> Seq Scan on public.plt2_l_p2 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: (t2_2.b > 250)
+ -> Seq Scan on public.plt2_l_p2_p1 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: (t2_3.b > 250)
+ -> Seq Scan on public.plt2_l_p2_p2 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: (t2_4.b > 250)
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Append
+ -> Seq Scan on public.plt1_l_p2 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a < 450) AND ((t1_2.a % 25) = 0))
+ -> Seq Scan on public.plt1_l_p2_p1 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a < 450) AND ((t1_3.a % 25) = 0))
+ -> Seq Scan on public.plt1_l_p2_p2 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a < 450) AND ((t1_4.a % 25) = 0))
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND (ltrim((t2_5.c)::text, 'A'::text) = ltrim((t1_5.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p1 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: (t2_5.b > 250)
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.plt1_l_p3_p1 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a < 450) AND ((t1_5.a % 25) = 0))
+ -> Hash Join
+ Output: t1_6.a, t1_6.c, t2_6.b, t2_6.c
+ Hash Cond: ((t2_6.b = t1_6.a) AND (t2_6.a = t1_6.b) AND ((t2_6.c)::text = (t1_6.c)::text) AND (ltrim((t2_6.c)::text, 'A'::text) = ltrim((t1_6.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p2 t2_6
+ Output: t2_6.b, t2_6.c, t2_6.a
+ Filter: (t2_6.b > 250)
+ -> Hash
+ Output: t1_6.a, t1_6.c, t1_6.b
+ -> Seq Scan on public.plt1_l_p3_p2 t1_6
+ Output: t1_6.a, t1_6.c, t1_6.b
+ Filter: ((t1_6.a < 450) AND ((t1_6.a % 25) = 0))
+(71 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 1) and (b 2) is considered for partition-wise join.
+NOTICE: join between relations (b 4) and (b 17) is considered for partition-wise join.
+NOTICE: join between relations (b 8) and (b 21) is considered for partition-wise join.
+NOTICE: join between relations (b 12) and (b 25) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0006 | 300 | 0006
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1, uplt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0006 | 300 | 0006
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Sort Key: plt1_l_p1_p1.a, plt2_l_p1_p1.b
+ -> Append
+ -> Nested Loop Left Join
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Join Filter: ((plt1_l_p1_p1.a = plt2_l_p1_p1.b) AND (plt1_l_p1_p1.b = plt2_l_p1_p1.a) AND ((plt1_l_p1_p1.c)::text = (plt2_l_p1_p1.c)::text) AND (ltrim((plt1_l_p1_p1.c)::text, 'A'::text) = ltrim((plt2_l_p1_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p1
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt1_l_p1_p1.b
+ Filter: ((plt1_l_p1_p1.a < 450) AND ((plt1_l_p1_p1.a % 25) = 0))
+ -> Seq Scan on public.plt2_l_p1_p1
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt2_l_p1_p1.a
+ Filter: (plt2_l_p1_p1.b > 250)
+ -> Hash Right Join
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt2_l_p1_p2.b, plt2_l_p1_p2.c
+ Hash Cond: ((plt2_l_p1_p2.b = plt1_l_p1_p2.a) AND (plt2_l_p1_p2.a = plt1_l_p1_p2.b) AND ((plt2_l_p1_p2.c)::text = (plt1_l_p1_p2.c)::text) AND (ltrim((plt2_l_p1_p2.c)::text, 'A'::text) = ltrim((plt1_l_p1_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p1_p2
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt2_l_p1_p2.a
+ Filter: (plt2_l_p1_p2.b > 250)
+ -> Hash
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt1_l_p1_p2.b
+ -> Seq Scan on public.plt1_l_p1_p2
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt1_l_p1_p2.b
+ Filter: ((plt1_l_p1_p2.a < 450) AND ((plt1_l_p1_p2.a % 25) = 0))
+ -> Hash Left Join
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.c, plt2_l_p2_p1.b, plt2_l_p2_p1.c
+ Hash Cond: ((plt1_l_p2_p1.a = plt2_l_p2_p1.b) AND (plt1_l_p2_p1.b = plt2_l_p2_p1.a) AND ((plt1_l_p2_p1.c)::text = (plt2_l_p2_p1.c)::text) AND (ltrim((plt1_l_p2_p1.c)::text, 'A'::text) = ltrim((plt2_l_p2_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p2_p1
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.c, plt1_l_p2_p1.b
+ Filter: ((plt1_l_p2_p1.a < 450) AND ((plt1_l_p2_p1.a % 25) = 0))
+ -> Hash
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ -> Seq Scan on public.plt2_l_p2_p1
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ Filter: (plt2_l_p2_p1.b > 250)
+ -> Hash Right Join
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt2_l_p2_p2.b, plt2_l_p2_p2.c
+ Hash Cond: ((plt2_l_p2_p2.b = plt1_l_p2_p2.a) AND (plt2_l_p2_p2.a = plt1_l_p2_p2.b) AND ((plt2_l_p2_p2.c)::text = (plt1_l_p2_p2.c)::text) AND (ltrim((plt2_l_p2_p2.c)::text, 'A'::text) = ltrim((plt1_l_p2_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p2_p2
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt2_l_p2_p2.a
+ Filter: (plt2_l_p2_p2.b > 250)
+ -> Hash
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt1_l_p2_p2.b
+ -> Seq Scan on public.plt1_l_p2_p2
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt1_l_p2_p2.b
+ Filter: ((plt1_l_p2_p2.a < 450) AND ((plt1_l_p2_p2.a % 25) = 0))
+ -> Hash Right Join
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt2_l_p3_p1.b, plt2_l_p3_p1.c
+ Hash Cond: ((plt2_l_p3_p1.b = plt1_l_p3_p1.a) AND (plt2_l_p3_p1.a = plt1_l_p3_p1.b) AND ((plt2_l_p3_p1.c)::text = (plt1_l_p3_p1.c)::text) AND (ltrim((plt2_l_p3_p1.c)::text, 'A'::text) = ltrim((plt1_l_p3_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p1
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt2_l_p3_p1.a
+ Filter: (plt2_l_p3_p1.b > 250)
+ -> Hash
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt1_l_p3_p1.b
+ -> Seq Scan on public.plt1_l_p3_p1
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt1_l_p3_p1.b
+ Filter: ((plt1_l_p3_p1.a < 450) AND ((plt1_l_p3_p1.a % 25) = 0))
+ -> Hash Right Join
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt2_l_p3_p2.b, plt2_l_p3_p2.c
+ Hash Cond: ((plt2_l_p3_p2.b = plt1_l_p3_p2.a) AND (plt2_l_p3_p2.a = plt1_l_p3_p2.b) AND ((plt2_l_p3_p2.c)::text = (plt1_l_p3_p2.c)::text) AND (ltrim((plt2_l_p3_p2.c)::text, 'A'::text) = ltrim((plt1_l_p3_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt2_l_p3_p2
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt2_l_p3_p2.a
+ Filter: (plt2_l_p3_p2.b > 250)
+ -> Hash
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt1_l_p3_p2.b
+ -> Seq Scan on public.plt1_l_p3_p2
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt1_l_p3_p2.b
+ Filter: ((plt1_l_p3_p2.a < 450) AND ((plt1_l_p3_p2.a % 25) = 0))
+(68 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | |
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uplt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | |
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 20) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 24) and (b 11) is considered for partition-wise join.
+NOTICE: join between relations (b 28) and (b 15) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Sort Key: plt1_l_p1_p1.a, plt2_l_p1_p1.b
+ -> Result
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ -> Append
+ -> Hash Right Join
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt1_l_p1_p1.a, plt1_l_p1_p1.c
+ Hash Cond: ((plt1_l_p1_p1.a = plt2_l_p1_p1.b) AND (plt1_l_p1_p1.b = plt2_l_p1_p1.a) AND ((plt1_l_p1_p1.c)::text = (plt2_l_p1_p1.c)::text) AND (ltrim((plt1_l_p1_p1.c)::text, 'A'::text) = ltrim((plt2_l_p1_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p1
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt1_l_p1_p1.b
+ Filter: (plt1_l_p1_p1.a < 450)
+ -> Hash
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt2_l_p1_p1.a
+ -> Seq Scan on public.plt2_l_p1_p1
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt2_l_p1_p1.a
+ Filter: ((plt2_l_p1_p1.b > 250) AND ((plt2_l_p1_p1.a % 25) = 0))
+ -> Hash Right Join
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt1_l_p1_p2.a, plt1_l_p1_p2.c
+ Hash Cond: ((plt1_l_p1_p2.a = plt2_l_p1_p2.b) AND (plt1_l_p1_p2.b = plt2_l_p1_p2.a) AND ((plt1_l_p1_p2.c)::text = (plt2_l_p1_p2.c)::text) AND (ltrim((plt1_l_p1_p2.c)::text, 'A'::text) = ltrim((plt2_l_p1_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p2
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt1_l_p1_p2.b
+ Filter: (plt1_l_p1_p2.a < 450)
+ -> Hash
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt2_l_p1_p2.a
+ -> Seq Scan on public.plt2_l_p1_p2
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt2_l_p1_p2.a
+ Filter: ((plt2_l_p1_p2.b > 250) AND ((plt2_l_p1_p2.a % 25) = 0))
+ -> Hash Right Join
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt1_l_p2_p1.a, plt1_l_p2_p1.c
+ Hash Cond: ((plt1_l_p2_p1.a = plt2_l_p2_p1.b) AND (plt1_l_p2_p1.b = plt2_l_p2_p1.a) AND ((plt1_l_p2_p1.c)::text = (plt2_l_p2_p1.c)::text) AND (ltrim((plt1_l_p2_p1.c)::text, 'A'::text) = ltrim((plt2_l_p2_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p2_p1
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.c, plt1_l_p2_p1.b
+ Filter: (plt1_l_p2_p1.a < 450)
+ -> Hash
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ -> Seq Scan on public.plt2_l_p2_p1
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ Filter: ((plt2_l_p2_p1.b > 250) AND ((plt2_l_p2_p1.a % 25) = 0))
+ -> Hash Right Join
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt1_l_p2_p2.a, plt1_l_p2_p2.c
+ Hash Cond: ((plt1_l_p2_p2.a = plt2_l_p2_p2.b) AND (plt1_l_p2_p2.b = plt2_l_p2_p2.a) AND ((plt1_l_p2_p2.c)::text = (plt2_l_p2_p2.c)::text) AND (ltrim((plt1_l_p2_p2.c)::text, 'A'::text) = ltrim((plt2_l_p2_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p2_p2
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt1_l_p2_p2.b
+ Filter: (plt1_l_p2_p2.a < 450)
+ -> Hash
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt2_l_p2_p2.a
+ -> Seq Scan on public.plt2_l_p2_p2
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt2_l_p2_p2.a
+ Filter: ((plt2_l_p2_p2.b > 250) AND ((plt2_l_p2_p2.a % 25) = 0))
+ -> Hash Right Join
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt1_l_p3_p1.a, plt1_l_p3_p1.c
+ Hash Cond: ((plt1_l_p3_p1.a = plt2_l_p3_p1.b) AND (plt1_l_p3_p1.b = plt2_l_p3_p1.a) AND ((plt1_l_p3_p1.c)::text = (plt2_l_p3_p1.c)::text) AND (ltrim((plt1_l_p3_p1.c)::text, 'A'::text) = ltrim((plt2_l_p3_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p3_p1
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt1_l_p3_p1.b
+ Filter: (plt1_l_p3_p1.a < 450)
+ -> Hash
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt2_l_p3_p1.a
+ -> Seq Scan on public.plt2_l_p3_p1
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt2_l_p3_p1.a
+ Filter: ((plt2_l_p3_p1.b > 250) AND ((plt2_l_p3_p1.a % 25) = 0))
+ -> Hash Right Join
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt1_l_p3_p2.a, plt1_l_p3_p2.c
+ Hash Cond: ((plt1_l_p3_p2.a = plt2_l_p3_p2.b) AND (plt1_l_p3_p2.b = plt2_l_p3_p2.a) AND ((plt1_l_p3_p2.c)::text = (plt2_l_p3_p2.c)::text) AND (ltrim((plt1_l_p3_p2.c)::text, 'A'::text) = ltrim((plt2_l_p3_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p3_p2
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt1_l_p3_p2.b
+ Filter: (plt1_l_p3_p2.a < 450)
+ -> Hash
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt2_l_p3_p2.a
+ -> Seq Scan on public.plt2_l_p3_p2
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt2_l_p3_p2.a
+ Filter: ((plt2_l_p3_p2.b > 250) AND ((plt2_l_p3_p2.a % 25) = 0))
+(72 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 5) and (b 4) is considered for partition-wise join.
+NOTICE: join between relations (b 20) and (b 7) is considered for partition-wise join.
+NOTICE: join between relations (b 24) and (b 11) is considered for partition-wise join.
+NOTICE: join between relations (b 28) and (b 15) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0006 | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uplt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0006 | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Sort Key: plt1_l_p1_p1.a, plt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt2_l_p1_p1.b, plt2_l_p1_p1.c
+ Hash Cond: ((plt1_l_p1_p1.a = plt2_l_p1_p1.b) AND (plt1_l_p1_p1.b = plt2_l_p1_p1.a) AND ((plt1_l_p1_p1.c)::text = (plt2_l_p1_p1.c)::text) AND (ltrim((plt1_l_p1_p1.c)::text, 'A'::text) = ltrim((plt2_l_p1_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p1
+ Output: plt1_l_p1_p1.a, plt1_l_p1_p1.c, plt1_l_p1_p1.b
+ Filter: ((plt1_l_p1_p1.a < 450) AND ((plt1_l_p1_p1.a % 25) = 0))
+ -> Hash
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt2_l_p1_p1.a
+ -> Seq Scan on public.plt2_l_p1_p1
+ Output: plt2_l_p1_p1.b, plt2_l_p1_p1.c, plt2_l_p1_p1.a
+ Filter: ((plt2_l_p1_p1.b > 250) AND ((plt2_l_p1_p1.b % 25) = 0))
+ -> Hash Full Join
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt2_l_p1_p2.b, plt2_l_p1_p2.c
+ Hash Cond: ((plt1_l_p1_p2.a = plt2_l_p1_p2.b) AND (plt1_l_p1_p2.b = plt2_l_p1_p2.a) AND ((plt1_l_p1_p2.c)::text = (plt2_l_p1_p2.c)::text) AND (ltrim((plt1_l_p1_p2.c)::text, 'A'::text) = ltrim((plt2_l_p1_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p1_p2
+ Output: plt1_l_p1_p2.a, plt1_l_p1_p2.c, plt1_l_p1_p2.b
+ Filter: ((plt1_l_p1_p2.a < 450) AND ((plt1_l_p1_p2.a % 25) = 0))
+ -> Hash
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt2_l_p1_p2.a
+ -> Seq Scan on public.plt2_l_p1_p2
+ Output: plt2_l_p1_p2.b, plt2_l_p1_p2.c, plt2_l_p1_p2.a
+ Filter: ((plt2_l_p1_p2.b > 250) AND ((plt2_l_p1_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.c, plt2_l_p2_p1.b, plt2_l_p2_p1.c
+ Hash Cond: ((plt1_l_p2_p1.a = plt2_l_p2_p1.b) AND (plt1_l_p2_p1.b = plt2_l_p2_p1.a) AND ((plt1_l_p2_p1.c)::text = (plt2_l_p2_p1.c)::text) AND (ltrim((plt1_l_p2_p1.c)::text, 'A'::text) = ltrim((plt2_l_p2_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p2_p1
+ Output: plt1_l_p2_p1.a, plt1_l_p2_p1.c, plt1_l_p2_p1.b
+ Filter: ((plt1_l_p2_p1.a < 450) AND ((plt1_l_p2_p1.a % 25) = 0))
+ -> Hash
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ -> Seq Scan on public.plt2_l_p2_p1
+ Output: plt2_l_p2_p1.b, plt2_l_p2_p1.c, plt2_l_p2_p1.a
+ Filter: ((plt2_l_p2_p1.b > 250) AND ((plt2_l_p2_p1.b % 25) = 0))
+ -> Hash Full Join
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt2_l_p2_p2.b, plt2_l_p2_p2.c
+ Hash Cond: ((plt1_l_p2_p2.a = plt2_l_p2_p2.b) AND (plt1_l_p2_p2.b = plt2_l_p2_p2.a) AND ((plt1_l_p2_p2.c)::text = (plt2_l_p2_p2.c)::text) AND (ltrim((plt1_l_p2_p2.c)::text, 'A'::text) = ltrim((plt2_l_p2_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p2_p2
+ Output: plt1_l_p2_p2.a, plt1_l_p2_p2.c, plt1_l_p2_p2.b
+ Filter: ((plt1_l_p2_p2.a < 450) AND ((plt1_l_p2_p2.a % 25) = 0))
+ -> Hash
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt2_l_p2_p2.a
+ -> Seq Scan on public.plt2_l_p2_p2
+ Output: plt2_l_p2_p2.b, plt2_l_p2_p2.c, plt2_l_p2_p2.a
+ Filter: ((plt2_l_p2_p2.b > 250) AND ((plt2_l_p2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt2_l_p3_p1.b, plt2_l_p3_p1.c
+ Hash Cond: ((plt1_l_p3_p1.a = plt2_l_p3_p1.b) AND (plt1_l_p3_p1.b = plt2_l_p3_p1.a) AND ((plt1_l_p3_p1.c)::text = (plt2_l_p3_p1.c)::text) AND (ltrim((plt1_l_p3_p1.c)::text, 'A'::text) = ltrim((plt2_l_p3_p1.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p3_p1
+ Output: plt1_l_p3_p1.a, plt1_l_p3_p1.c, plt1_l_p3_p1.b
+ Filter: ((plt1_l_p3_p1.a < 450) AND ((plt1_l_p3_p1.a % 25) = 0))
+ -> Hash
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt2_l_p3_p1.a
+ -> Seq Scan on public.plt2_l_p3_p1
+ Output: plt2_l_p3_p1.b, plt2_l_p3_p1.c, plt2_l_p3_p1.a
+ Filter: ((plt2_l_p3_p1.b > 250) AND ((plt2_l_p3_p1.b % 25) = 0))
+ -> Hash Full Join
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt2_l_p3_p2.b, plt2_l_p3_p2.c
+ Hash Cond: ((plt1_l_p3_p2.a = plt2_l_p3_p2.b) AND (plt1_l_p3_p2.b = plt2_l_p3_p2.a) AND ((plt1_l_p3_p2.c)::text = (plt2_l_p3_p2.c)::text) AND (ltrim((plt1_l_p3_p2.c)::text, 'A'::text) = ltrim((plt2_l_p3_p2.c)::text, 'A'::text)))
+ -> Seq Scan on public.plt1_l_p3_p2
+ Output: plt1_l_p3_p2.a, plt1_l_p3_p2.c, plt1_l_p3_p2.b
+ Filter: ((plt1_l_p3_p2.a < 450) AND ((plt1_l_p3_p2.a % 25) = 0))
+ -> Hash
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt2_l_p3_p2.a
+ -> Seq Scan on public.plt2_l_p3_p2
+ Output: plt2_l_p3_p2.b, plt2_l_p3_p2.c, plt2_l_p3_p2.a
+ Filter: ((plt2_l_p3_p2.b > 250) AND ((plt2_l_p3_p2.b % 25) = 0))
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') ORDER BY t1.a, t2.b;
+NOTICE: join between relations (b 4) and (b 5) is considered for partition-wise join.
+NOTICE: join between relations (b 7) and (b 20) is considered for partition-wise join.
+NOTICE: join between relations (b 11) and (b 24) is considered for partition-wise join.
+NOTICE: join between relations (b 15) and (b 28) is considered for partition-wise join.
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | |
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | |
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(12 rows)
+
+-- joins where one of the relations is proven empty
+--Getting cannot use column or expression from ancestor partition key error
+--for declarative partitioning code posted on 15 sep, and getting server crash
+--for partition-wise-join code posted on 2009, so need to generate output once
+--declarative code fixed.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a = 1 AND t1.a = 2;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a = 1 AND t1.a = 2;
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+--Getting cannot use column or expression from ancestor partition key error
+--for declarative partitioning code posted on 15 sep, and getting server crash
+--for partition-wise-join code posted on 2009, so need to generate output once
+--declarative code fixed.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A');
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A');
+ a | c | b | c
+---+---+---+---
+(0 rows)
+
+--Getting cannot use column or expression from ancestor partition key error
+--for declarative partitioning code posted on 15 sep, and getting server crash
+--for partition-wise-join code posted on 2009, so need to generate output once
+--declarative code fixed.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+--Getting cannot use column or expression from ancestor partition key error
+--for declarative partitioning code posted on 15 sep, and getting server crash
+--for partition-wise-join code posted on 2009, so need to generate output once
+--declarative code fixed.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+---+---+-----+------
+ | | 0 | 0000
+ | | 75 | 0001
+ | | 150 | 0003
+ | | 225 | 0004
+ | | 300 | 0006
+ | | 375 | 0007
+ | | 450 | 0009
+ | | 525 | 0010
+(8 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1_l t1 WHERE t1.c IN (SELECT t1.c FROM plt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+ QUERY PLAN
+---------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: ((t1.c)::text = (t1_7.c)::text)
+ -> Seq Scan on public.plt1_l_p1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_7.c
+ -> Seq Scan on public.plt2_l_p1_p1 t1_7
+ Output: t1_7.c
+ Filter: ((t1_7.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: ((t1_1.c)::text = (t1_8.c)::text)
+ -> Seq Scan on public.plt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_8.c
+ -> Seq Scan on public.plt2_l_p1_p2 t1_8
+ Output: t1_8.c
+ Filter: ((t1_8.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: ((t1_2.c)::text = (t1_9.c)::text)
+ -> Seq Scan on public.plt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_9.c
+ -> Seq Scan on public.plt2_l_p2_p1 t1_9
+ Output: t1_9.c
+ Filter: ((t1_9.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Join Filter: ((t1_3.c)::text = (t1_10.c)::text)
+ -> Seq Scan on public.plt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Materialize
+ Output: t1_10.c
+ -> Seq Scan on public.plt2_l_p2_p2 t1_10
+ Output: t1_10.c
+ Filter: ((t1_10.b % 25) = 0)
+ -> Hash Semi Join
+ Output: t1_4.a, t1_4.b, t1_4.c
+ Hash Cond: ((t1_4.c)::text = (t1_11.c)::text)
+ -> Append
+ -> Seq Scan on public.plt1_l_p3 t1_4
+ Output: t1_4.a, t1_4.b, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.plt1_l_p3_p1 t1_5
+ Output: t1_5.a, t1_5.b, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+ -> Seq Scan on public.plt1_l_p3_p2 t1_6
+ Output: t1_6.a, t1_6.b, t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Hash
+ Output: t1_11.c
+ -> Append
+ -> Seq Scan on public.plt2_l_p3 t1_11
+ Output: t1_11.c
+ Filter: ((t1_11.b % 25) = 0)
+ -> Seq Scan on public.plt2_l_p3_p1 t1_12
+ Output: t1_12.c
+ Filter: ((t1_12.b % 25) = 0)
+ -> Seq Scan on public.plt2_l_p3_p2 t1_13
+ Output: t1_13.c
+ Filter: ((t1_13.b % 25) = 0)
+(73 rows)
+
+SELECT t1.* FROM plt1_l t1 WHERE t1.c IN (SELECT t1.c FROM plt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+NOTICE: join between relations (b 1) and (b 3) is considered for partition-wise join.
+NOTICE: join between relations (b 5) and (b 18) is considered for partition-wise join.
+NOTICE: join between relations (b 9) and (b 22) is considered for partition-wise join.
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+SELECT t1.* FROM uplt1_l t1 WHERE t1.c IN (SELECT t1.c FROM uplt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
--
-- negative testcases
--
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
index 45e8a64..fa16354 100644
--- a/src/test/regress/sql/partition_join.sql
+++ b/src/test/regress/sql/partition_join.sql
@@ -467,6 +467,59 @@ SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
(SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM (SELECT 50 phv, * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and t2.a + t2.b = t1.b + t1.a) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+SELECT * FROM (SELECT 50 phv, * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and t2.a + t2.b = t1.b + t1.a) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+SELECT * FROM (SELECT 50 phv, * FROM uprt1_l WHERE uprt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2_l WHERE uprt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and t2.a + t2.b = t1.b + t1.a) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b ORDER BY t1.a, t2.b;
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a = 1 AND t1.a = 2;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1_l t1 WHERE t1.a IN (SELECT t1.b FROM prt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1_l t1 WHERE t1.a IN (SELECT t1.b FROM prt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1_l t1 WHERE t1.a IN (SELECT t1.b FROM uprt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
--
-- tests for list partitioned tables.
--
@@ -555,6 +608,48 @@ SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25
SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2 t2 ON t1.a = t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 FULL JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE a = 1 AND a = 2) t1 FULL JOIN plt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 WHERE a = 1 AND a = 2) t1 FULL JOIN uplt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM uplt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM uplt1 t2 JOIN uplt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+
--
-- list partitioned by expression
--
@@ -648,6 +743,13 @@ SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (
SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, ltrim(t3.c,'A'), t3.phv FROM ((SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c)) FULL JOIN (SELECT '0002'::text phv, * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.c = ltrim(t3.c,'A')) WHERE t1.a = t1.phv OR t2.b = t2.phv OR ltrim(t3.c,'A') = t3.phv ORDER BY t1.a, t2.b, ltrim(t3.c,'A');
+SELECT t1.a, t1.phv, t2.b, t2.phv, ltrim(t3.c,'A'), t3.phv FROM ((SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c)) FULL JOIN (SELECT '0002'::text phv, * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.c = ltrim(t3.c,'A')) WHERE t1.a = t1.phv OR t2.b = t2.phv OR ltrim(t3.c,'A') = t3.phv ORDER BY t1.a, t2.b, ltrim(t3.c,'A');
+SELECT t1.a, t1.phv, t2.b, t2.phv, ltrim(t3.c,'A'), t3.phv FROM ((SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c)) FULL JOIN (SELECT '0002'::text phv, * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.c = ltrim(t3.c,'A')) WHERE t1.a = t1.phv OR t2.b = t2.phv OR ltrim(t3.c,'A') = t3.phv ORDER BY t1.a, t2.b, ltrim(t3.c,'A');
+
-- test merge join with and without index scan
CREATE INDEX iplt1_c on plt1(c);
CREATE INDEX iplt1_p1_c on plt1_p1(c);
@@ -710,11 +812,182 @@ SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (
SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM uplt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.c AS t2c, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM uplt1 t2 JOIN uplt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM plt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM plt1 t2 JOIN plt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
+SELECT distinct * FROM uplt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.c AS t3c, least(t1.c,t2.c,t3.c) FROM uplt1 t2 JOIN uplt2 t3 ON (t2.c = t3.c)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY 1,2,3,4,5,6;
RESET enable_hashjoin;
RESET enable_nestloop;
RESET enable_seqscan;
--
+-- multi-leveled partitions
+--
+CREATE TABLE plt1_l (a int, b int, c varchar) PARTITION BY LIST(c);
+CREATE TABLE plt1_l_p1 PARTITION OF plt1_l FOR VALUES IN ('0000', '0003', '0004', '0010') PARTITION BY LIST (c);
+CREATE TABLE plt1_l_p1_p1 PARTITION OF plt1_l_p1 FOR VALUES IN ('0000', '0003');
+CREATE TABLE plt1_l_p1_p2 PARTITION OF plt1_l_p1 FOR VALUES IN ('0004', '0010');
+CREATE TABLE plt1_l_p2 PARTITION OF plt1_l FOR VALUES IN ('0001', '0005', '0002', '0009') PARTITION BY LIST (c);
+CREATE TABLE plt1_l_p2_p1 PARTITION OF plt1_l_p2 FOR VALUES IN ('0001', '0005');
+CREATE TABLE plt1_l_p2_p2 PARTITION OF plt1_l_p2 FOR VALUES IN ('0002', '0009');
+CREATE TABLE plt1_l_p3 PARTITION OF plt1_l FOR VALUES IN ('0006', '0007', '0008', '0011') PARTITION BY LIST (ltrim(c,'A'));
+CREATE TABLE plt1_l_p3_p1 PARTITION OF plt1_l_p3 FOR VALUES IN ('0006', '0007');
+CREATE TABLE plt1_l_p3_p2 PARTITION OF plt1_l_p3 FOR VALUES IN ('0008', '0011');
+INSERT INTO plt1_l SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_l;
+ANALYZE plt1_l_p1;
+ANALYZE plt1_l_p1_p1;
+ANALYZE plt1_l_p1_p2;
+ANALYZE plt1_l_p2;
+ANALYZE plt1_l_p2_p1;
+ANALYZE plt1_l_p2_p2;
+ANALYZE plt1_l_p3;
+ANALYZE plt1_l_p3_p1;
+ANALYZE plt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_l AS SELECT * FROM plt1_l;
+
+CREATE TABLE plt2_l (a int, b int, c varchar) PARTITION BY LIST(c);
+CREATE TABLE plt2_l_p1 PARTITION OF plt2_l FOR VALUES IN ('0000', '0003', '0004', '0010') PARTITION BY LIST (c);
+CREATE TABLE plt2_l_p1_p1 PARTITION OF plt2_l_p1 FOR VALUES IN ('0000', '0003');
+CREATE TABLE plt2_l_p1_p2 PARTITION OF plt2_l_p1 FOR VALUES IN ('0004', '0010');
+CREATE TABLE plt2_l_p2 PARTITION OF plt2_l FOR VALUES IN ('0001', '0005', '0002', '0009') PARTITION BY LIST (c);
+CREATE TABLE plt2_l_p2_p1 PARTITION OF plt2_l_p2 FOR VALUES IN ('0001', '0005');
+CREATE TABLE plt2_l_p2_p2 PARTITION OF plt2_l_p2 FOR VALUES IN ('0002', '0009');
+CREATE TABLE plt2_l_p3 PARTITION OF plt2_l FOR VALUES IN ('0006', '0007', '0008', '0011') PARTITION BY LIST (ltrim(c,'A'));
+CREATE TABLE plt2_l_p3_p1 PARTITION OF plt2_l_p3 FOR VALUES IN ('0006', '0007');
+CREATE TABLE plt2_l_p3_p2 PARTITION OF plt2_l_p3 FOR VALUES IN ('0008', '0011');
+INSERT INTO plt2_l SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_l;
+ANALYZE plt2_l_p1;
+ANALYZE plt2_l_p1_p1;
+ANALYZE plt2_l_p1_p2;
+ANALYZE plt2_l_p2;
+ANALYZE plt2_l_p2_p1;
+ANALYZE plt2_l_p2_p2;
+ANALYZE plt2_l_p3;
+ANALYZE plt2_l_p3_p1;
+ANALYZE plt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_l AS SELECT * FROM plt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1, uplt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1 LEFT JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1 RIGHT JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A')) ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uplt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM uplt1_l t2 JOIN uplt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM plt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM plt1_l t2 JOIN plt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uplt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.c,t2.c,t3.c) FROM uplt1_l t2 JOIN uplt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND ltrim(t2.c,'A') = ltrim(t3.c,'A'))) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND ltrim(t1.c,'A') = ltrim(ss.t2c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM (SELECT 50 phv, * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and ltrim(t2.c,'A') = ltrim(t1.c,'A')) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+SELECT * FROM (SELECT 50 phv, * FROM plt1_l WHERE plt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2_l WHERE plt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and ltrim(t2.c,'A') = ltrim(t1.c,'A')) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+SELECT * FROM (SELECT 50 phv, * FROM uplt1_l WHERE uplt1_l.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2_l WHERE uplt2_l.b % 25 = 0) t2 ON (t1.a = t2.b and t1.b = t2.a and t1.c = t2.c and ltrim(t2.c,'A') = ltrim(t1.c,'A')) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY 1,2,3,4,5,6,7,8;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_l t1, uplt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uplt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM plt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uplt2_l WHERE b > 250) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_l WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') ORDER BY t1.a, t2.b;
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a = 1 AND t1.a = 2;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_l t1, plt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A');
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 LEFT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A');
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a = 1 AND a = 2) t1 RIGHT JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN plt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_l WHERE a = 1 AND a = 2) t1 FULL JOIN uplt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND ltrim(t1.c,'A') = ltrim(t2.c,'A') WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1_l t1 WHERE t1.c IN (SELECT t1.c FROM plt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1_l t1 WHERE t1.c IN (SELECT t1.c FROM plt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1_l t1 WHERE t1.c IN (SELECT t1.c FROM uplt2_l t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
-- negative testcases
--
On Thu, Sep 22, 2016 at 6:41 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
[ new patch ]
This should probably get updated since Rajkumar reported a crash.
Meanwhile, here are some comments from an initial read-through:
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting be partitioned in the same as the underlying relations.
I think you should change "may be partitioned in the same way" to "are
partitioned in the same way" or "can be regarded as partitioned in the
same way". The sentence that begins with "Similarly," is not
grammatical; it should say something like: ...by grouping or sorting
are partitioned in the same way as the underlying relations.
@@ -870,20 +902,21 @@ RelationBuildPartitionDesc(Relation rel)
result->bounds->rangeinfo = rangeinfo;
break;
}
}
}
MemoryContextSwitchTo(oldcxt);
rel->rd_partdesc = result;
}
+
/*
* Are two partition bound collections logically equal?
*
* Used in the keep logic of relcache.c (ie, in RelationClearRelation()).
* This is also useful when b1 and b2 are bound collections of two separate
* relations, respectively, because BoundCollection is a canonical
* representation of a set partition bounds (for given partitioning strategy).
*/
bool
partition_bounds_equal(PartitionKey key,
Spurious hunk.
+ * For an umpartitioned table, it returns NULL.
Spelling.
+ * two arguemnts and returns boolean. For types, it
suffices to match
Spelling.
+ * partition key expression is stored as a single member list to accomodate
Spelling.
+ * For a base relation, construct an array of partition key expressions. Each
+ * partition key expression is stored as a single member list to accomodate
+ * more partition keys when relations are joined.
How would joining relations result in more partitioning keys getting
added? Especially given the comment for the preceding function, which
says that a new PartitionScheme gets created unless an exact match is
found.
+ if (!lc)
Test lc == NIL instead of !lc.
+extern int
+PartitionSchemeGetNumParts(PartitionScheme part_scheme)
+{
+ return part_scheme ? part_scheme->nparts : 0;
+}
I'm not convinced it's a very good idea for this function to have
special handling for when part_scheme is NULL. In
try_partition_wise_join() that checks is not needed because it's
already been done, and in generate_partition_wise_join_paths it is
needed but only because you are initializing nparts too early. If you
move this initialization down below the IS_DUMMY_REL() check you won't
need the NULL guard. I would ditch this function and let the callers
access the structure member directly.
+extern int
+PartitionSchemeGetNumKeys(PartitionScheme part_scheme)
+{
+ return part_scheme ? part_scheme->partnatts : 0;
+}
Similarly here. have_partkey_equi_join should probably have a
quick-exit path when part_scheme is NULL, and then num_pks can be set
afterwards unconditionally. Same for match_expr_to_partition_keys.
build_joinrel_partition_info already has it and doesn't need this
double-check.
+extern Oid *
+PartitionDescGetPartOids(PartitionDesc part_desc)
+{
+ Oid *part_oids;
+ int cnt_parts;
+
+ if (!part_desc || part_desc->nparts <= 0)
+ return NULL;
+
+ part_oids = (Oid *) palloc(sizeof(Oid) * part_desc->nparts);
+ for (cnt_parts = 0; cnt_parts < part_desc->nparts; cnt_parts++)
+ part_oids[cnt_parts] = part_desc->oids[cnt_parts];
+
+ return part_oids;
+}
I may be missing something, but this looks like a bad idea in multiple
ways. First, you've got checks for part_desc's validity here that
should be in the caller, as noted above. Second, you're copying an
array by looping instead of using memcpy(). Third, the one and only
caller is set_append_rel_size, which doesn't seem to have any need to
copy this data in the first place. If there is any possibility that
the PartitionDesc is going to change under us while that function is
running, something is deeply broken. Nothing in the planner is going
to cope with the table structure changing under us, so it had better
not.
+ /*
+ * For a partitioned relation, we will save the child RelOptInfos in parent
+ * RelOptInfo in the same the order as corresponding bounds/lists are
+ * stored in the partition scheme.
+ */
This comment seems misplaced; shouldn't it be next to the code that is
actually doing this, rather than the code that is merely setting up
for it? And, also, the comment implies that we're doing this instead
of what we'd normally do, whereas I think we are actually doing
something additional.
+ /*
+ * Save topmost parent's relid. If the parent itself is a child of some
+ * other relation, use parent's topmost parent relids.
+ */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
Comment should explain why we're doing it, not what we're doing. The
comment as written just restates what anybody who's likely to be
looking at this can already see to be true from looking at the code
that follows. The question is why do it.
+ /* Set only for "other" base or join relations. */
+ Relids top_parent_relids;
Comment should say what it is, not just when it's set.
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ Assert(rel->part_rels[cnt_parts]);
+ }
A block that does nothing but Assert() should be guarded by #ifdef
USE_ASSERT_CHECKING. Although, actually, maybe this should be an
elog(), just in case?
+ }
+
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
The new function should have a header comment, which should include an
explanation of why this is now separate from
set_append_rel_pathlist().
+ if (!live_childrels)
As before, I think live_childrels == NIL is better style.
+ generate_partition_wise_join_paths(root, rel);
Needs an update to the comment earlier in the hunk. It's important to
explain why this has to be done here and not within
join_search_one_level.
+ /* Recursively collect the paths from child joinrel. */
+ generate_partition_wise_join_paths(root, child_rel);
Given the recursion, check_stack_depth() at top of function is
probably appropriate. Same for try_partition_wise_join().
+ if (live_children)
+ pfree(live_children);
Given that none of the substructure, including ListCells, will be
freed, this seems utterly pointless. If it's necessary to recover
memory here at all, we probably need to be more aggressive about it.
Have you tested the effect of this patch on planner memory consumption
with multi-way joins between tables with many partitions? If you
haven't, you probably should. (Testing runtime would be good, too.)
Does it grow linearly? Quadratically? Exponentially? Minor leaks
don't matter, but if we're generating too much garbage we'll have to
make sure it gets cleaned up soon enough to prevent runaway memory
usage.
/*
+ * An inner path parameterized by the parent relation of outer
+ * relation needs to be reparameterized by the outer relation to be used
+ * for parameterized nested loop join.
+ */
No doubt, but I think the comment is missing the bigger picture -- it
doesn't say anything about this being here to support partition-wise
joins, which seems like a key point.
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
Why would that ever happen?
+/*
+ * If the join between the given two relations can be executed as
+ * partition-wise join create the join relations for partition-wise join,
+ * create paths for those and then create append paths to combine
+ * partition-wise join results.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
This comment doesn't accurately describe what the function does. No
append paths are created here; that happens at a much later stage. I
think this comment needs quite a bit more work, and maybe the function
should be renamed, too. There are really two steps involved here:
first, we create paths for each child, attached to a new RelOptInfo
flagged as RELOPT_OTHER_JOINREL paths; later, we create additional
paths for the parent RelOptInfo by appending a path for each child.
Broadly, I think there's a lack of adequate documentation of the
overall theory of operation of this patch. I believe that an update
to the optimizer README would be appropriate, probably with a new
section but maybe incorporating the new material into an existing
section. In addition, the comments for individual comments and chunks
of code need to do a better job explaining how each part of the patch
contributes to the overall picture. I also think we need to do a
better join hammering out the terminology. I don't particularly like
the term "partition-wise join" in the first place, although I don't
know what would be better, but we certainly need to avoid confusing a
partition-wise join -- which is a join performed by joining each
partition of one partitioned rel to the corresponding partition of a
similarly partitioned rel rather than by the usual execution strategy
of joining the parent rels -- with the concept of an other-join-rel,
which an other-member-rel analogue for joins. I don't think the patch
is currently very clear about this right now, either in the code or in
the comments. Maybe this function ought to be named something like
make_child_joins() or make_child_join_paths(), and we could use "child
joins" and/or "child join paths" as standard terminology throughout
the patch.
+ rel1_desc = makeStringInfo();
+ rel2_desc = makeStringInfo();
+
+ /* TODO: remove this notice when finalising the patch. */
+ outBitmapset(rel1_desc, rel1->relids);
+ outBitmapset(rel2_desc, rel2->relids);
+ elog(NOTICE, "join between relations %s and %s is considered for
partition-wise join.",
+ rel1_desc->data, rel2_desc->data);
Please remove your debugging cruft before submitting patches to
pgsql-hackers, or at least put #ifdef NOT_USED or something around it.
+ * We allocate the array for child RelOptInfos till we find at least one
+ * join order which can use partition-wise join technique. If no join order
+ * can use partition-wise join technique, there are no child relations.
This comment has problems. I think "till" is supposed to be "until",
and there's supposed to be a "don't" in there somewhere. But really,
I think what you're going for is just /* Allocate when first needed */
which would be a lot shorter and also more clear.
+ * Create join relations for the partition relations, if they do not exist
+ * already. Add paths to those for the given pair of joining relations.
I think the comment could be a bit more explanatory here. Something
like: "This joinrel is partitioned, so iterate over the partitions and
create paths for each one, allowing us to eventually build an
append-of-joins path for the parent. Since this routine may be called
multiple times for various join orders, the RelOptInfo needed for each
child join may or may not already exist, but the paths for this join
order definitely do not. Note that we don't create any actual
AppendPath at this stage; it only makes sense to do that at the end,
after each possible join order has been considered for each child
join. The best join order may differ from child to child."
+ * partiticipating in the given partition relations. We need them
Spelling.
+/*
+ * Construct the SpecialJoinInfo for the partition-wise join using parents'
+ * special join info. Also, instead of
+ * constructing an sjinfo everytime, we should probably save it in
+ * root->join_info_list and search within it like join_is_legal?
+ */
The lines here are of very different lengths for no particularly good
reason, and it should end with a period, not a question mark.
On the substance of the issue, it seems like the way you're doing this
right now could allocate a very large number of SpecialJoinInfo
structures. For every join relation, you'll create one
SpecialJoinInfo per legal join order per partition. That seems like
it could get to be a big number. I don't know if that's going to be a
problem from a memory-usage standpoint, but it seems like it might.
It's not just the SpecialJoinInfo itself; all of the substructure gets
duplicated, too.
+ SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo);
+ sjinfo->min_lefthand = adjust_partition_relids(sjinfo->min_lefthand,
+ append_rel_infos1);
Missing a blank line here.
+ AppendRelInfo *ari = lfirst(lc);
Standard naming convention for an AppendRelInfo variable seems to be
appinfo, not ari. (I just did "git grep AppendRelInfo".)
+ /* Skip non-equi-join clauses. */
+ if (!rinfo->can_join ||
+ rinfo->hashjoinoperator == InvalidOid ||
+ !rinfo->mergeopfamilies)
+ continue;
There's definitely something ugly about this. If rinfo->can_join is
false, then we're done. But suppose one of mergeopfamilies == NIL and
rinfo->hashoperator == InvalidOid is true and the other is false. Are
we really precluded from doing a partiion-wise join in that case, or
are we just prohibited from using certain join strategies? In most
places where we make similar tests, we're careful not to require more
than we need.
I also think that these tests need to consider the partitioning
operator in use. Suppose that the partition key is of a type T which
has two operator classes X and Y. Both relations are partitioned
using an operator from opfamily X, but the join condition mentions
opfamily Y. I'm pretty sure this precludes a partitionwise join. If
the join condition used opfamily X, then we would have a guarantee
that two rows which compared as equal would be in the same partition,
but because it uses opfamily Y, that's not guaranteed. For example,
if T is a text type, X might test for exact equality using "C"
collation rules, while Y might test for equality using some
case-insensitive set of rules. If the partition boundaries are such
that "foo" and "FOO" are in different partitions, a partitionwise join
using the case-insensitive operator will produce wrong results. You
can also imagine this happening with numeric, if you have one opclass
(like the default one) that considers 5.0 and 5.00 to be equal, but
another opclass that thinks they are different; if the latter is used
to set the partition bounds, 5.0 and 5.00 could end up in different
partitions - which will be fine if an operator from that opclass is
used for the join, but not if an operator from the regular opclass is
used.
After thinking this over a bit, I think the right way to think about this is:
1. Amit's patch currently only ever uses btree opfamilies for
partitioning. It uses those for both range partitioning and list
partitioning. If we ever support hash partitioning, we would
presumably use hash opfamilies for that purpose, but right now it's
all about btree opfamilies.
2. Therefore, if A and B are partitioned but the btree opfamilies
don't match, they don't have the same partitioning scheme and this
code should never be reached. Similarly, if they use the same
opfamily but different collations, the partitioning schemes shouldn't
match and therefore this code should not be reached.
3. If A and B are partitioned and the partitioning opfamilies - which
are necessarily btree opfamilies - do match, then the operator which
appears in the query needs to be from the same opfamily and have
amopstrategy of BTEqualStrategyNumber within that opfamily. If not,
then a partition-wise join is not possible.
4. Assuming the above conditions are met, have_partkey_equi_join
doesn't need to care whether the operator chosen has mergeopfamilies
or a valid hashjoinoperator. Those factors will control which join
methods are legal, but not whether a partitionwise join is possible in
principle.
Let me know whether that seems right.
+ * RelabelType node; eval_const_expressions() will have simplied if more
Spelling.
/*
+ * Code below scores equivalence classes by how many equivalence members
+ * can produce join clauses for this join relation. Equivalence members
+ * which do not cover the parents of a partition-wise join relation, can
+ * produce join clauses for partition-wise join relation.
+ */
I don't know what that means. The comma in the second sentence
doesn't belong there.
+ /*
+ * TODO: Instead of copying and mutating the trees one child relation at a
+ * time, we should be able to do this en-masse for all the partitions
+ * involved.
+ */
I don't see how that would be possible, but if it's a TODO, you'd
better do it (or decide not to do it and remove or change the
comment).
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
The changes related to make_sort_from_pathkeys() are pretty opaque to
me. Can you explain?
+ * Change parameterization of sub paths recursively. Also carry out any
"sub paths" should not be two words, here or anywhere.
+reparameterize_path_for_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
This is suspiciously unlike reparameterize_path. Why?
+ /* Computer information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
Perhaps this refactoring could be split out into a preliminary patch,
which would then simplify this patch. And same for add_join_rel().
+ * Produce partition-wise joinrel's targetlist by translating the parent
+ * joinrel's targetlist. This will also include the required placeholder
Again the confusion between a "child" join and a partition-wise join...
+ /*
+ * Nothing to do if
+ * a. partition-wise join is disabled.
+ * b. joining relations are not partitioned.
+ * c. partitioning schemes do not match.
+ */
+
I don't think that's going to survive pgindent.
+ * are not considered equal, an equi-join involing inner partition keys
Spelling.
+ * Collect the partition key expressions. An OUTER join will produce rows
+ * where the partition key columns of inner side are NULL and may not fit
+ * the partitioning scheme with inner partition keys. Since two NULL values
+ * are not considered equal, an equi-join involing inner partition keys
+ * still prohibits cross-partition joins while joining with another
+ * similarly partitioned relation.
I can't figure out what this comment is trying to tell me. Possibly I
just need more caffeine.
+ * Adding these two join_rel_level list also means that top level list has more
+ * than one join relation, which is symantically incorrect.
I don't understand this, either; also, spelling.
As a general comment, the ratio of tests-to-code in this patch is way
out of line with PostgreSQL's normal practices. The total patch file
is 10965 lines. The test cases begin at line 3047, meaning that in
round figures you've got about one-quarter code and about
three-quarters test cases. I suspect that a large fraction of those
test cases aren't adding any meaningful code coverage and will just
take work to maintain. That needs to be slimmed down substantially in
any version of this considered for commit.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Wed, Sep 28, 2016 at 2:02 AM, Robert Haas <robertmhaas@gmail.com> wrote:
On Thu, Sep 22, 2016 at 6:41 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:[ new patch ]
This should probably get updated since Rajkumar reported a crash.
Meanwhile, here are some comments from an initial read-through:
Done. Fixed those crashes. Also fixed some crashes in foreign table
code and postgres_fdw. The tests were provided by Rajkumar. I am
working on including those in my patch. The attached patch is still
based on Amit's patches set of patches posted on 15th Sept. 2016. He
is addressing your comments on his patches. So, I am expecting a more
stable version arrive soon. I will rebase my patches then. Because of
a bug in those patches related to multi-level partitioned tables and
lateral joins and also a restriction on sharing partition keys across
levels of partitions, the testcase is still failing. I will work on
that while rebasing the patch.
+ * Multiple relations may be partitioned in the same way. The relations + * resulting from joining such relations may be partitioned in the same way as + * the joining relations. Similarly, relations derived from such relations by + * grouping, sorting be partitioned in the same as the underlying relations.I think you should change "may be partitioned in the same way" to "are
partitioned in the same way" or "can be regarded as partitioned in the
same way".
The relations resulting from joining partitioned relations are
partitioned in the same way, if there exist equi-join condition/s
between their partition keys. If such equi-joins do not exist, the
join is *not* partitioned. Hence I did not use "are" or "can be" which
indicate a certainty. Instead I used "may" which indicates
"uncertainty". I am not sure whether that's a good place to explain
the conditions under which such relations are partitioned. Those
conditions will change as we implement more and more partition-wise
join strategies. But that comment conveys two things 1. partition
scheme makes sense for all kinds of relations 2. multiple relations
(of any kind) may share partition scheme. I have slightly changed the
wording to make this point clear. Please let me know if it looks
better.
The sentence that begins with "Similarly," is not
grammatical; it should say something like: ...by grouping or sorting
are partitioned in the same way as the underlying relations.
Done. Instead of "are" I have used "may" for the same reason as above.
@@ -870,20 +902,21 @@ RelationBuildPartitionDesc(Relation rel)
result->bounds->rangeinfo = rangeinfo;
break;
}
}
}MemoryContextSwitchTo(oldcxt);
rel->rd_partdesc = result;
}+
/*
* Are two partition bound collections logically equal?
*
* Used in the keep logic of relcache.c (ie, in RelationClearRelation()).
* This is also useful when b1 and b2 are bound collections of two separate
* relations, respectively, because BoundCollection is a canonical
* representation of a set partition bounds (for given partitioning strategy).
*/
bool
partition_bounds_equal(PartitionKey key,Spurious hunk.
Thanks. Done.
+ * For an umpartitioned table, it returns NULL.
Spelling.
Done. Thanks.
+ * two arguemnts and returns boolean. For types, it
suffices to matchSpelling.
Thanks. Done.
+ * partition key expression is stored as a single member list to accomodate
Spelling.
Thanks. Done.
+ * For a base relation, construct an array of partition key expressions. Each + * partition key expression is stored as a single member list to accomodate + * more partition keys when relations are joined.How would joining relations result in more partitioning keys getting
added? Especially given the comment for the preceding function, which
says that a new PartitionScheme gets created unless an exact match is
found.
Let's assume that relation A and B are partitioned by columns a and b
resp. and have same partitioning scheme. This means that the datatypes
of a and b as well as the opclass used for comparing partition key
values of A and B are same. A join between A and B with condition A.a
= B.b is partitioned by both A.a and B.b. We need to keep track of
both the keys in case AB joins with C which is partitioned in the same
manner. I guess, the confusion is with the term "partition keys" -
which is being used to indicate the class of partition key as well as
instance of partition key. In the above example, the datatype of
partition key and the opclass together indicate partition key class
whereas A.a and B.b are instances of that class. Increase in partition
keys may mean both increase in the number of classes or increase in
the number of instances. In the above comment I used to mean number of
instances. May be we should use "partition key expressions" to
indicate the partition key instances and "partition key" to indicate
partition key class. I have changed the comments to use partition keys
and partition key expressions appropriately. Please let me know if the
comments are worded correctly.
PartitionScheme does not hold the actual partition key expressions. It
holds the partition key type and opclass used for comparison, which
should be same for all the relations sharing the partition scheme.
+ if (!lc)
Test lc == NIL instead of !lc.
NIL is defined as (List *) NULL and lc is ListCell *. So changed the
test to lc == NULL instead of !lc.
+extern int +PartitionSchemeGetNumParts(PartitionScheme part_scheme) +{ + return part_scheme ? part_scheme->nparts : 0; +}I'm not convinced it's a very good idea for this function to have
special handling for when part_scheme is NULL. In
try_partition_wise_join() that checks is not needed because it's
already been done, and in generate_partition_wise_join_paths it is
needed but only because you are initializing nparts too early. If you
move this initialization down below the IS_DUMMY_REL() check you won't
need the NULL guard. I would ditch this function and let the callers
access the structure member directly.+extern int +PartitionSchemeGetNumKeys(PartitionScheme part_scheme) +{ + return part_scheme ? part_scheme->partnatts : 0; +}Similarly here. have_partkey_equi_join should probably have a
quick-exit path when part_scheme is NULL, and then num_pks can be set
afterwards unconditionally. Same for match_expr_to_partition_keys.
build_joinrel_partition_info already has it and doesn't need this
double-check.+extern Oid * +PartitionDescGetPartOids(PartitionDesc part_desc) +{ + Oid *part_oids; + int cnt_parts; + + if (!part_desc || part_desc->nparts <= 0) + return NULL; + + part_oids = (Oid *) palloc(sizeof(Oid) * part_desc->nparts); + for (cnt_parts = 0; cnt_parts < part_desc->nparts; cnt_parts++) + part_oids[cnt_parts] = part_desc->oids[cnt_parts]; + + return part_oids; +}I may be missing something, but this looks like a bad idea in multiple
ways. First, you've got checks for part_desc's validity here that
should be in the caller, as noted above. Second, you're copying an
array by looping instead of using memcpy(). Third, the one and only
caller is set_append_rel_size, which doesn't seem to have any need to
copy this data in the first place. If there is any possibility that
the PartitionDesc is going to change under us while that function is
running, something is deeply broken. Nothing in the planner is going
to cope with the table structure changing under us, so it had better
not.
These three functions were written based on Amit Langote's patches
which did not expose partition related structures outside partition.c.
Hence they required wrappers. I have moved PartitionSchemeData to
partition.h and removed these functions. Instead the members are
accessed directly.
+ /* + * For a partitioned relation, we will save the child RelOptInfos in parent + * RelOptInfo in the same the order as corresponding bounds/lists are + * stored in the partition scheme. + */This comment seems misplaced; shouldn't it be next to the code that is
actually doing this, rather than the code that is merely setting up
for it? And, also, the comment implies that we're doing this instead
of what we'd normally do, whereas I think we are actually doing
something additional.
Ok. I have moved the comment few line below, near the code which saves
the partition RelOptInfos.
+ /* + * Save topmost parent's relid. If the parent itself is a child of some + * other relation, use parent's topmost parent relids. + */ + if (rel->top_parent_relids) + childrel->top_parent_relids = rel->top_parent_relids; + else + childrel->top_parent_relids = bms_copy(rel->relids);Comment should explain why we're doing it, not what we're doing. The
comment as written just restates what anybody who's likely to be
looking at this can already see to be true from looking at the code
that follows. The question is why do it.
The point of that comment is to explain how it percolates down the
hierarchy, which is not so clear from the code. I have changed it to
read
/*
* Recursively save topmost parent's relid in RelOptInfos of
* partitions.
*/
Or you are expecting that the comment to explain the purpose of
top_parent_relids? I don't think that's a good idea, since the purpose
will change over the time and the comment will soon be out of sync
with the actual code, unless the developers expanding the usage
remember to update the comment. I have not seen the comments,
explaining purpose, next to the assignments. Take for example
RelOptInfo::relids.
+ /* Set only for "other" base or join relations. */ + Relids top_parent_relids;Comment should say what it is, not just when it's set.
Done. Check if it looks good.
+ /* Should have found all the childrels of a partitioned relation. */ + if (rel->part_scheme) + { + int cnt_parts; + for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++) + Assert(rel->part_rels[cnt_parts]); + }A block that does nothing but Assert() should be guarded by #ifdef
USE_ASSERT_CHECKING. Although, actually, maybe this should be an
elog(), just in case?
Changed it to elog().
+ } + + add_paths_to_append_rel(root, rel, live_childrels); +} + +static void +add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel, + List *live_childrels)The new function should have a header comment, which should include an
explanation of why this is now separate from
set_append_rel_pathlist().
Sorry for missing it. Added the prologue. Let me know, if it looks
good. I have made sure that all functions have a prologue and tried to
match the style with surrounding functions. Let me know if I have
still missed any or the styles do not match.
+ if (!live_childrels)
As before, I think live_childrels == NIL is better style.
Fixed.
+ generate_partition_wise_join_paths(root, rel);
Needs an update to the comment earlier in the hunk. It's important to
explain why this has to be done here and not within
join_search_one_level.
Thanks for pointing that out. Similar to generate_gather_paths(), we
need to add explanation in standard_join_search() as well as in the
function prologue. Did that. Let me know if it looks good.
+ /* Recursively collect the paths from child joinrel. */ + generate_partition_wise_join_paths(root, child_rel);Given the recursion, check_stack_depth() at top of function is
probably appropriate. Same for try_partition_wise_join().
Done. I wouldn't imagine a user creating that many levels of
partitions, but it's good to guard against some automated script that
has gone berserk.
+ if (live_children)
+ pfree(live_children);Given that none of the substructure, including ListCells, will be
freed, this seems utterly pointless. If it's necessary to recover
memory here at all, we probably need to be more aggressive about it.
I intended to use list_free() instead of pfree(). Fixed that.
Have you tested the effect of this patch on planner memory consumption
with multi-way joins between tables with many partitions? If you
haven't, you probably should. (Testing runtime would be good, too.)
Does it grow linearly? Quadratically? Exponentially? Minor leaks
don't matter, but if we're generating too much garbage we'll have to
make sure it gets cleaned up soon enough to prevent runaway memory
usage.
I tried to check memory usage with various combinations of number of
partitions and number of relations being joined. For higher number of
relations being joined like 10 with 100 partitions, OOM killer kicked
in during the planning phase. I am suspecting
adjust_partitionrel_attrs() (changed that name to
adjust_join_appendrel_attrs() to be in sync with
adjust_appendrel_attrs()) to be the culprit. It copies expression
trees every time for joining two children. That's an exponentially
increasing number as the number of legal joins increases
exponentially. I am still investigating this.
As a side question, do we have a function to free an expression tree?
I didn't find any.
/* + * An inner path parameterized by the parent relation of outer + * relation needs to be reparameterized by the outer relation to be used + * for parameterized nested loop join. + */No doubt, but I think the comment is missing the bigger picture -- it
doesn't say anything about this being here to support partition-wise
joins, which seems like a key point.
I have tried to explain the partition-wise join context. Let me know
if it looks good.
+ /* If we could not translate the path, don't produce nest loop path. */ + if (!inner_path) + return;Why would that ever happen?
Right now, reparameterize_path_for_child() does not support all kinds
of paths. So I have added that condition. I will add support for more
path types there once we agree that this is the right way to translate
the paths and that the path translation is required.
+/* + * If the join between the given two relations can be executed as + * partition-wise join create the join relations for partition-wise join, + * create paths for those and then create append paths to combine + * partition-wise join results. + */ +static void +try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2, + RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo, + List *parent_restrictlist)This comment doesn't accurately describe what the function does. No
append paths are created here; that happens at a much later stage.
Removed reference to the append paths. Sorry for leaving it there,
when I moved the append path creation to a later stage.
I
think this comment needs quite a bit more work, and maybe the function
should be renamed, too.
Improved the comments in the prologue and inside the function. Please
let me know, if they look good.
There are really two steps involved here:
first, we create paths for each child, attached to a new RelOptInfo
flagged as RELOPT_OTHER_JOINREL paths; later, we create additional
paths for the parent RelOptInfo by appending a path for each child.
Right, the first one is done in try_partition_wise_join() and the
later is done in generate_partition_wise_join_paths()
Broadly, I think there's a lack of adequate documentation of the
overall theory of operation of this patch. I believe that an update
to the optimizer README would be appropriate, probably with a new
section but maybe incorporating the new material into an existing
section.
Done. I have added a separate section to optimizer/README
In addition, the comments for individual comments and chunks
of code need to do a better job explaining how each part of the patch
contributes to the overall picture.
I also think we need to do a
better join hammering out the terminology. I don't particularly like
the term "partition-wise join" in the first place, although I don't
know what would be better, but we certainly need to avoid confusing a
partition-wise join -- which is a join performed by joining each
partition of one partitioned rel to the corresponding partition of a
similarly partitioned rel rather than by the usual execution strategy
of joining the parent rels -- with the concept of an other-join-rel,
which an other-member-rel analogue for joins. I don't think the patch
is currently very clear about this right now, either in the code or in
the comments. Maybe this function ought to be named something like
make_child_joins() or make_child_join_paths(), and we could use "child
joins" and/or "child join paths" as standard terminology throughout
the patch.
Partition-wise join is widely used term in the literature. Other
DBMSes use the same term as well. So, I think we should stick with
"partition-wise join". Partition-wise join as you have described is a
join performed by joining each partition of one partitioned rel to the
corresponding partition of a similarly partitioned rel rather than by
the usual execution strategy of joining the parent rels. I have
usually used the term "partition-wise join technique" to refer to this
method. I have changed the other usages of this term to use wording
like child joins or join between partiitions or join between child
relations as appropriate. Also, I have changed the names of functions
dealing with joins between partitions to use child_join instead of
partition_join or partition_wise_join.
Since partition-wise join is a method to join two relations just like
other methods, try_partition_wise_join() fits into the naming
convention try_<join technique> like try_nestloop_join.
+ rel1_desc = makeStringInfo(); + rel2_desc = makeStringInfo(); + + /* TODO: remove this notice when finalising the patch. */ + outBitmapset(rel1_desc, rel1->relids); + outBitmapset(rel2_desc, rel2->relids); + elog(NOTICE, "join between relations %s and %s is considered for partition-wise join.", + rel1_desc->data, rel2_desc->data);Please remove your debugging cruft before submitting patches to
pgsql-hackers, or at least put #ifdef NOT_USED or something around it.
I kept this one intentionally. But as the TODO comment says, I do
intend to remove it once testing is over. Those messages make it very
easy to know whether partition-wise join was considered for a given
join or not. Without those messages, one has to break into
try_partition_wise_join() to figure out whether partition-wise join
was used or not. The final plan may not come out to be partition-wise
join plan even if partition-wise join was considered. Although, I have
now used DEBUG3 instead of NOTICE and removed those lines from the
expected output.
+ * We allocate the array for child RelOptInfos till we find at least one + * join order which can use partition-wise join technique. If no join order + * can use partition-wise join technique, there are no child relations.This comment has problems. I think "till" is supposed to be "until",
and there's supposed to be a "don't" in there somewhere. But really,
I think what you're going for is just /* Allocate when first needed */
which would be a lot shorter and also more clear.
Sorry for those mistakes. Yes, shorter version is better. Fixed the
comment as per your suggestion.
+ * Create join relations for the partition relations, if they do not exist + * already. Add paths to those for the given pair of joining relations.I think the comment could be a bit more explanatory here. Something
like: "This joinrel is partitioned, so iterate over the partitions and
create paths for each one, allowing us to eventually build an
append-of-joins path for the parent. Since this routine may be called
multiple times for various join orders, the RelOptInfo needed for each
child join may or may not already exist, but the paths for this join
order definitely do not. Note that we don't create any actual
AppendPath at this stage; it only makes sense to do that at the end,
after each possible join order has been considered for each child
join. The best join order may differ from child to child."
Copied verbatim. Thanks for the detailed comment.
+ * partiticipating in the given partition relations. We need them
Spelling.
Done. Also fixed other grammatical mistakes and typos in that comment.
+/* + * Construct the SpecialJoinInfo for the partition-wise join using parents' + * special join info. Also, instead of + * constructing an sjinfo everytime, we should probably save it in + * root->join_info_list and search within it like join_is_legal? + */The lines here are of very different lengths for no particularly good
reason, and it should end with a period, not a question mark.
My bad. Sorry. Fixed.
On the substance of the issue, it seems like the way you're doing this
right now could allocate a very large number of SpecialJoinInfo
structures. For every join relation, you'll create one
SpecialJoinInfo per legal join order per partition. That seems like
it could get to be a big number. I don't know if that's going to be a
problem from a memory-usage standpoint, but it seems like it might.
It's not just the SpecialJoinInfo itself; all of the substructure gets
duplicated, too.
Yes. We need the SpecialJoinInfo structures for the existing path
creation to work. The code will be complicated if we try to use parent
SpecialJoinInfo instead of creating those for children. We may free
memory allocated in SpecialJoinInfo to save some memory.
SpecialJoinInfos are not needed once the paths are created. Still we
will waste some memory for semi_rhs_exprs, which are reused for unique
paths. But otherwise we will reclaim the rest of the memory. Memory
wastage in adjust_partition_relids() may be minimized by modifying
adjust_appendrel_attrs() to accept list of AppendRelInfos and mutating
the tree only once rather than doing it N times for an N-way join.
+ SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo); + sjinfo->min_lefthand = adjust_partition_relids(sjinfo->min_lefthand, + append_rel_infos1);Missing a blank line here.
Done.
+ AppendRelInfo *ari = lfirst(lc);
Standard naming convention for an AppendRelInfo variable seems to be
appinfo, not ari. (I just did "git grep AppendRelInfo".)
Done.
+ /* Skip non-equi-join clauses. */ + if (!rinfo->can_join || + rinfo->hashjoinoperator == InvalidOid || + !rinfo->mergeopfamilies) + continue;There's definitely something ugly about this. If rinfo->can_join is
false, then we're done. But suppose one of mergeopfamilies == NIL and
rinfo->hashoperator == InvalidOid is true and the other is false. Are
we really precluded from doing a partiion-wise join in that case, or
are we just prohibited from using certain join strategies? In most
places where we make similar tests, we're careful not to require more
than we need.
Right. That condition is flawed. Corrected it.
I also think that these tests need to consider the partitioning
operator in use. Suppose that the partition key is of a type T which
has two operator classes X and Y. Both relations are partitioned
using an operator from opfamily X, but the join condition mentions
opfamily Y. I'm pretty sure this precludes a partitionwise join. If
the join condition used opfamily X, then we would have a guarantee
that two rows which compared as equal would be in the same partition,
but because it uses opfamily Y, that's not guaranteed. For example,
if T is a text type, X might test for exact equality using "C"
collation rules, while Y might test for equality using some
case-insensitive set of rules. If the partition boundaries are such
that "foo" and "FOO" are in different partitions, a partitionwise join
using the case-insensitive operator will produce wrong results. You
can also imagine this happening with numeric, if you have one opclass
(like the default one) that considers 5.0 and 5.00 to be equal, but
another opclass that thinks they are different; if the latter is used
to set the partition bounds, 5.0 and 5.00 could end up in different
partitions - which will be fine if an operator from that opclass is
used for the join, but not if an operator from the regular opclass is
used.
Your description above uses opfamily and opclass interchangeably. It
starts saying X and Y are classed but then also refers to them as
families. But I got the point. I guess, similar to
relation_has_unique_index_for(), I have to check whether the operator
family specified in the partition scheme is present in the
mergeopfamilies in RestrictInfo for matching partition key. I have
added that check and restructured that portion of code to be readable.
After thinking this over a bit, I think the right way to think about this is:
1. Amit's patch currently only ever uses btree opfamilies for
partitioning. It uses those for both range partitioning and list
partitioning. If we ever support hash partitioning, we would
presumably use hash opfamilies for that purpose, but right now it's
all about btree opfamilies.2. Therefore, if A and B are partitioned but the btree opfamilies
don't match, they don't have the same partitioning scheme and this
code should never be reached. Similarly, if they use the same
opfamily but different collations, the partitioning schemes shouldn't
match and therefore this code should not be reached.
That's right.
3. If A and B are partitioned and the partitioning opfamilies - which
are necessarily btree opfamilies - do match, then the operator which
appears in the query needs to be from the same opfamily and have
amopstrategy of BTEqualStrategyNumber within that opfamily. If not,
then a partition-wise join is not possible.
I think this is achieved by checking whether the opfamily for given
partition key is present in the mergeopfamilies of corresponding
RestrictInfo, as stated above.
4. Assuming the above conditions are met, have_partkey_equi_join
doesn't need to care whether the operator chosen has mergeopfamilies
or a valid hashjoinoperator. Those factors will control which join
methods are legal, but not whether a partitionwise join is possible in
principle.
If mergeopfamilies is NIL, above check will fail anyway. But skipping
a clause which has mergeopfamilies NIL will save some cycles in
matching expressions.
There is something strange happening with Amit's patch. When we create
a table partitioned by range on a column of type int2vector, it
somehow gets a btree operator family, but doesn't have mergeopfamilies
set in RestrictInfo of equality condition on that column. Instead the
RestrictInfo has hashjoinoperator. In this case if we ignore
hashjoinoperator, we won't be able to apply partition-wise join. I
guess, in such case we want to play safe and not apply partition-wise
join, even though applying it will give the correct result.
+ * RelabelType node; eval_const_expressions() will have simplied if more
Spelling.
Thanks. Done.
/* + * Code below scores equivalence classes by how many equivalence members + * can produce join clauses for this join relation. Equivalence members + * which do not cover the parents of a partition-wise join relation, can + * produce join clauses for partition-wise join relation. + */I don't know what that means. The comma in the second sentence
doesn't belong there.
Sorry for that construction. I have changed the comment to be
something more meaningful.
+ /* + * TODO: Instead of copying and mutating the trees one child relation at a + * time, we should be able to do this en-masse for all the partitions + * involved. + */I don't see how that would be possible, but if it's a TODO, you'd
better do it (or decide not to do it and remove or change the
comment).
That should be doable by passing a list of AppendRelInfo structures to
adjust_appendrel_attrs_mutator(). In the mutator, we have to check
each appinfo instead of just one. But that's a lot of refactoring. May
be done as a separate patch, if we are consuming too much memory. I
have removed TODO for now.
/* * Create explicit sort nodes for the outer and inner paths if necessary. */ if (best_path->outersortkeys) { + Relids outer_relids = outer_path->parent->relids; Sort *sort = make_sort_from_pathkeys(outer_plan, - best_path->outersortkeys); + best_path->outersortkeys, + outer_relids);The changes related to make_sort_from_pathkeys() are pretty opaque to
me. Can you explain?
prepare_sort_from_pathkeys() accepts Relids as one of the argument to
find equivalence members belonging to child relations. The function
does not expect relids when searching equivalence members for parent
relations. Before this patch, make_sort_from_pathkeys() passed NULL to
this function, because it didn't expect child relations before.
Because of partition-wise joins, we need to sort child relations for
merge join or to create unique paths. So, make_sort_from_pathkeys() is
required to pass relids to prepare_sort_from_pathkeys() when
processing child relations, so that the later does not skip child
members.
+ * Change parameterization of sub paths recursively. Also carry out any
"sub paths" should not be two words, here or anywhere.
Fixed.
+reparameterize_path_for_child(PlannerInfo *root, Path *path, + RelOptInfo *child_rel)This is suspiciously unlike reparameterize_path. Why?
reparameterize_path() tries to create path with new parameterization
from an existing parameterized path. So, it looks for additional
conditions to expand the parameterization. But this functions
translates a path parameterized by parent to be parameterized by its
child. That does not involve looking for any extra conditions, but
involves translating the existing ones so that they can be used with a
child. A right name would be translate_parampath_to_child() or
something which uses word "translate" instead of "reparameterize". But
every name like that is getting too long. For now I have renamed it as
reparameterize_path_by_child(). Also added a comment in the function
prologue about cost, rows, width etc.
+ /* Computer information relevant to the foreign relations. */ + set_foreign_rel_properties(joinrel, outer_rel, inner_rel);Perhaps this refactoring could be split out into a preliminary patch,
which would then simplify this patch. And same for add_join_rel().
Yes, that's better. I will separate the code out in a separate patch.
There's code in build_join_rel() and build_partition_join_rel() (I
will change that name) which creates a joinrel RelOptInfo. Most of
that code simply sets NULL or 0 fields and is duplicated in both the
functions. Do you see any value in separating it out in its own
function?
Also, makeNode() uses palloc0(), thus makeNode(RelOptInfo) would set
most of the fields to 0 or NULL. Why do we then again set those fields
as NULL or 0? Should I try to remove unnecessary assignments?
+ * Produce partition-wise joinrel's targetlist by translating the parent + * joinrel's targetlist. This will also include the required placeholderAgain the confusion between a "child" join and a partition-wise join...
+ /* + * Nothing to do if + * a. partition-wise join is disabled. + * b. joining relations are not partitioned. + * c. partitioning schemes do not match. + */ +I don't think that's going to survive pgindent.
Changed this code a bit.
+ * are not considered equal, an equi-join involing inner partition keys
Spelling.
+ * Collect the partition key expressions. An OUTER join will produce rows + * where the partition key columns of inner side are NULL and may not fit + * the partitioning scheme with inner partition keys. Since two NULL values + * are not considered equal, an equi-join involing inner partition keys + * still prohibits cross-partition joins while joining with another + * similarly partitioned relation.I can't figure out what this comment is trying to tell me. Possibly I
just need more caffeine.
Re-wrote the comment with examples and detailed explanation. The
comment talks about whether inner partition key expressions should be
considered as the partition key expressions for the join, given that
for an OUTER join the inner partition key expressions may go NULL. The
comment explains why it's safe to do so. If we don't do that, any FULL
OUTER join will have no partition expressions and thus partition-wise
join technique will be useless for a N-way FULL OUTER join even if
it's safe to use it.
+ * Adding these two join_rel_level list also means that top level list has more + * than one join relation, which is symantically incorrect.I don't understand this, either; also, spelling.
I think, that sentence is not required. Removed it.
As a general comment, the ratio of tests-to-code in this patch is way
out of line with PostgreSQL's normal practices. The total patch file
is 10965 lines. The test cases begin at line 3047, meaning that in
round figures you've got about one-quarter code and about
three-quarters test cases. I suspect that a large fraction of those
test cases aren't adding any meaningful code coverage and will just
take work to maintain. That needs to be slimmed down substantially in
any version of this considered for commit.
I agree. We require two kinds of tests 1. those which test partition
scheme matching 2. those test the planner code, which deals with path
creation. I have added both kinds of testcases for all kinds of
partitioning schemes (range, list, multi-level, partition key being
expressions, columns). That's not required. We need 1st kind of tests
for all partitioning schemes and 2nd kind of testcases only for one of
the partitioning schemes. So, definitely the number of tests will
reduce. A possible extreme would be to use a single multi-level
partitioned tests, which includes all kinds of partitioning schemes at
various partition levels. But that kind of testcase will be highly
unreadable and harder to maintain. Let me know what do you think. I
will work on that in the next version of patch. The test still fails
because of a bug in Amit's earlier set of patches
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_v4.patchtext/plain; charset=US-ASCII; name=pg_dp_join_v4.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 691658f..287c7d5 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -763,21 +763,21 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
* List of columns selected is returned in retrieved_attrs.
*/
extern void
deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
List *tlist, List *remote_conds, List *pathkeys,
List **retrieved_attrs, List **params_list)
{
deparse_expr_cxt context;
/* We handle relations for foreign tables and joins between those */
- Assert(rel->reloptkind == RELOPT_JOINREL ||
+ Assert(IS_JOIN_REL(rel) ||
rel->reloptkind == RELOPT_BASEREL ||
rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
/* Fill portions of context common to join and base relation */
context.buf = buf;
context.root = root;
context.foreignrel = rel;
context.params_list = params_list;
/* Construct SELECT clause and FROM clause */
@@ -817,21 +817,21 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
StringInfo buf = context->buf;
RelOptInfo *foreignrel = context->foreignrel;
PlannerInfo *root = context->root;
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
/*
* Construct SELECT list
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
/* For a join relation use the input tlist */
deparseExplicitTargetList(tlist, retrieved_attrs, context);
}
else
{
/*
* For a base relation fpinfo->attrs_used gives the list of columns
* required to be fetched from the foreign server.
*/
@@ -845,22 +845,21 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
deparseTargetList(buf, root, foreignrel->relid, rel, false,
fpinfo->attrs_used, false, retrieved_attrs);
heap_close(rel, NoLock);
}
/*
* Construct FROM clause
*/
appendStringInfoString(buf, " FROM ");
- deparseFromExprForRel(buf, root, foreignrel,
- (foreignrel->reloptkind == RELOPT_JOINREL),
+ deparseFromExprForRel(buf, root, foreignrel, IS_JOIN_REL(foreignrel),
context->params_list);
}
/*
* Emit a target list that retrieves the columns specified in attrs_used.
* This is used for both SELECT and RETURNING targetlists; the is_returning
* parameter is true only for a RETURNING targetlist.
*
* The tlist text is appended to buf, and we also create an integer List
* of the columns being retrieved, which is returned to *retrieved_attrs.
@@ -981,21 +980,21 @@ deparseLockingClause(deparse_expr_cxt *context)
* before 8.3.
*/
if (relid == root->parse->resultRelation &&
(root->parse->commandType == CMD_UPDATE ||
root->parse->commandType == CMD_DELETE))
{
/* Relation is UPDATE/DELETE target, so use FOR UPDATE */
appendStringInfoString(buf, " FOR UPDATE");
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(rel))
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
else
{
PlanRowMark *rc = get_plan_rowmark(root->rowMarks, relid);
if (rc)
{
/*
* Relation is specified as a FOR UPDATE/SHARE target, so
@@ -1017,22 +1016,21 @@ deparseLockingClause(deparse_expr_cxt *context)
case LCS_FORSHARE:
appendStringInfoString(buf, " FOR SHARE");
break;
case LCS_FORNOKEYUPDATE:
case LCS_FORUPDATE:
appendStringInfoString(buf, " FOR UPDATE");
break;
}
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL &&
- rc->strength != LCS_NONE)
+ if (IS_JOIN_REL(rel) && rc->strength != LCS_NONE)
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
}
}
}
/*
* Deparse conditions from the provided list and append them to buf.
*
* The conditions in the list are assumed to be ANDed. This function is used to
@@ -1155,21 +1153,21 @@ deparseExplicitTargetList(List *tlist, List **retrieved_attrs,
* The function constructs ... JOIN ... ON ... for join relation. For a base
* relation it just returns schema-qualified tablename, with the appropriate
* alias if so requested.
*/
static void
deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
bool use_alias, List **params_list)
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
RelOptInfo *rel_o = fpinfo->outerrel;
RelOptInfo *rel_i = fpinfo->innerrel;
StringInfoData join_sql_o;
StringInfoData join_sql_i;
/* Deparse outer relation */
initStringInfo(&join_sql_o);
deparseFromExprForRel(&join_sql_o, root, rel_o, true, params_list);
@@ -1860,21 +1858,21 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
* Deparse given Var node into context->buf.
*
* If the Var belongs to the foreign relation, just print its remote name.
* Otherwise, it's effectively a Param (and will in fact be a Param at
* run time). Handle it the same way we handle plain Params --- see
* deparseParam for comments.
*/
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL);
+ bool qualify_col = IS_JOIN_REL(context->foreignrel);
if (bms_is_member(node->varno, context->foreignrel->relids) &&
node->varlevelsup == 0)
deparseColumnRef(context->buf, node->varno, node->varattno,
context->root, qualify_col);
else
{
/* Treat like a Param */
if (context->params_list)
{
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index daf0438..594292a 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -1163,21 +1163,21 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
else if (is_foreign_expr(root, foreignrel, rinfo->clause))
{
remote_conds = lappend(remote_conds, rinfo);
remote_exprs = lappend(remote_exprs, rinfo->clause);
}
else
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
/* For a join relation, get the conditions from fdw_private structure */
remote_conds = fpinfo->remote_conds;
local_exprs = fpinfo->local_conds;
/* Build the list of columns to be fetched from the foreign server. */
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
/*
* Ensure that the outer plan produces a tuple whose descriptor
@@ -1221,21 +1221,21 @@ postgresGetForeignPlan(PlannerInfo *root,
&retrieved_attrs, ¶ms_list);
/*
* Build the fdw_private list that will be available to the executor.
* Items in the list must match order in enum FdwScanPrivateIndex.
*/
fdw_private = list_make4(makeString(sql.data),
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
/*
* Create the ForeignScan node for the given relation.
*
* Note that the remote parameter expressions are stored in the fdw_exprs
* field of the finished plan node; we can't keep them in private state
* because then they wouldn't be subject to later planner processing.
*/
@@ -2498,21 +2498,21 @@ estimate_path_cost_size(PlannerInfo *root,
List *retrieved_attrs;
/*
* param_join_conds might contain both clauses that are safe to send
* across, and clauses that aren't.
*/
classifyConditions(root, foreignrel, param_join_conds,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
fdw_scan_tlist = NIL;
/*
* The complete list of remote conditions includes everything from
* baserestrictinfo plus any extra join_conds relevant to this
* particular path.
*/
remote_conds = list_concat(list_copy(remote_param_join_conds),
@@ -2579,21 +2579,21 @@ estimate_path_cost_size(PlannerInfo *root,
* We will come here again and again with different set of pathkeys
* that caller wants to cost. We don't need to calculate the cost of
* bare scan each time. Instead, use the costs if we have cached them
* already.
*/
if (fpinfo->rel_startup_cost > 0 && fpinfo->rel_total_cost > 0)
{
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind != RELOPT_JOINREL)
+ else if (!IS_JOIN_REL(foreignrel))
{
/* Clamp retrieved rows estimates to at most foreignrel->tuples. */
retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
/*
* Cost as though this were a seqscan, which is pessimistic. We
* effectively imagine the local_conds are being evaluated
* remotely, too.
*/
startup_cost = 0;
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index 1a60563..dc2b34b 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -13,38 +13,41 @@
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/nbtree.h"
#include "access/sysattr.h"
#include "catalog/dependency.h"
+#include "catalog/heap.h"
#include "catalog/indexing.h"
#include "catalog/objectaddress.h"
#include "catalog/partition.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_inherits.h"
#include "catalog/pg_inherits_fn.h"
#include "catalog/pg_opclass.h"
#include "catalog/pg_partitioned_table.h"
#include "catalog/pg_partitioned_table_fn.h"
#include "catalog/pg_type.h"
#include "executor/executor.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "nodes/parsenodes.h"
#include "optimizer/clauses.h"
+#include "optimizer/cost.h"
#include "optimizer/planmain.h"
#include "optimizer/var.h"
+#include "rewrite/rewriteManip.h"
#include "storage/lmgr.h"
#include "utils/array.h"
#include "utils/builtins.h"
#include "utils/datum.h"
#include "utils/memutils.h"
#include "utils/fmgroids.h"
#include "utils/inval.h"
#include "utils/lsyscache.h"
#include "utils/ruleutils.h"
#include "utils/rel.h"
@@ -2412,20 +2415,78 @@ make_range_bound(PartitionKey key, List *val, bool inclusive, bool lower)
key->tcinfo->typbyval[i],
key->tcinfo->typlen[i]);
i++;
}
}
return bound;
}
/*
+ * Return a copy of input BoundCollection structure containg nparts number of
+ * partitions. The data types of bounds are described by given partition key
+ * specificiation.
+ */
+static BoundCollection
+copy_bounds(BoundCollection src_bounds, PartitionKey key, int nparts)
+{
+ BoundCollection dst_bounds;
+ int i;
+
+ dst_bounds = (BoundCollection) palloc(sizeof(BoundCollectionData));
+
+ if (src_bounds->listinfo)
+ {
+ ListInfo *dst_li = (ListInfo *) palloc(sizeof(ListInfo));
+ ListInfo *src_li = src_bounds->listinfo;
+
+ Assert(!src_bounds->rangeinfo);
+ dst_bounds->rangeinfo = NULL;
+
+ /* Copy the ListInfo structure. */
+ dst_li->nvalues = src_li->nvalues;
+ dst_li->has_null = src_li->has_null;
+ dst_li->null_index = src_li->null_index;
+
+ dst_li->values = (Datum *) palloc(sizeof(Datum) * dst_li->nvalues);
+ dst_li->indexes = (int *) palloc(sizeof(int) * dst_li->nvalues);
+ for (i = 0; i < dst_li->nvalues; i++)
+ {
+ dst_li->values[i] = datumCopy(src_li->values[i],
+ key->tcinfo->typbyval[0],
+ key->tcinfo->typlen[0]);
+ dst_li->indexes[i] = src_li->indexes[i];
+ }
+
+ dst_bounds->listinfo = dst_li;
+ }
+ else
+ {
+ RangeInfo *dst_ri = (RangeInfo *) palloc(sizeof(RangeInfo));
+ RangeInfo *src_ri = src_bounds->rangeinfo;
+
+ Assert(!src_bounds->listinfo && src_bounds->rangeinfo);
+ dst_bounds->listinfo = NULL;
+
+ /* Copy RangeInfo structure. */
+ dst_ri = (RangeInfo *) palloc(sizeof(RangeInfo));
+ dst_ri->ranges = (PartitionRange **) palloc(sizeof(PartitionRange *) * nparts);
+ for (i = 0; i < nparts; i++)
+ dst_ri->ranges[i] = copy_range(src_ri->ranges[i], key);
+
+ dst_bounds->rangeinfo = dst_ri;
+ }
+
+ return dst_bounds;
+}
+
+/*
* Make and return a copy of input PartitionRange.
*/
static PartitionRange *
copy_range(PartitionRange *src, PartitionKey key)
{
PartitionRange *result;
result = (PartitionRange *) palloc0(sizeof(PartitionRange));
result->lower = copy_range_bound(src->lower, key);
result->upper = copy_range_bound(src->upper, key);
@@ -2647,10 +2708,175 @@ tuple_rightof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound)
static bool
tuple_leftof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound)
{
int32 cmpval = partition_range_tuple_cmp(key, tuple, bound->val);
if (!cmpval)
return !bound->lower ? bound->inclusive : !bound->inclusive;
return cmpval < 0;
}
+
+/*
+ * find_partition_scheme
+ * Find the "canonical" partition scheme for the given base table.
+ *
+ * The function searches the list of canonical partition schemes for one that
+ * exactly matches the partitioning properties of the given relation. If it
+ * does not find one, the function creates a canonical partition scheme
+ * structure and adds it to the list.
+ *
+ * For an unpartitioned table, it returns NULL.
+ */
+
+extern PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * It suffices to check the OID of support function as it always has
+ * two arguments and returns boolean. For types, it suffices to match
+ * the type id, mod and collation; len, byval and align are depedent on
+ * the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->tcinfo->typid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->tcinfo->typmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->tcinfo->typcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->bounds,
+ part_scheme->bounds, nparts))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->bounds = copy_bounds(part_desc->bounds, part_key,
+ part_scheme->nparts);
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ part_scheme->partopfamily[cnt_pks] = part_key->partopfamily[cnt_pks];
+ part_scheme->partopcintype[cnt_pks] = part_key->partopcintype[cnt_pks];
+ part_scheme->key_types[cnt_pks] = part_key->tcinfo->typid[cnt_pks];
+ part_scheme->key_typmods[cnt_pks] = part_key->tcinfo->typmod[cnt_pks];
+ part_scheme->key_collations[cnt_pks] = part_key->tcinfo->typcoll[cnt_pks];
+ }
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_key_exprs
+ * Collect partition key expressions for a given base relation.
+ *
+ * The function converts single column partition keys into corresponding Var
+ * nodes. It restamps Var nodes in partition key expressions by given varno.
+ * The partition key expressions are returned as an array of Lists to be stored
+ * in RelOptInfo of the base relation.
+ */
+extern List **
+build_baserel_partition_key_exprs(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (lc == NULL)
+ elog(ERROR, "wrong number of partition key expressions");
+
+ /* Re-stamp the expressions with given varno. */
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 242d6d2..75c95e4 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -714,21 +714,21 @@ get_foreign_server_oid(const char *servername, bool missing_ok)
* Since the plan created using this path will presumably only be used to
* execute EPQ checks, efficiency of the path is not a concern. But since the
* path list in RelOptInfo is anyway sorted by total cost we are likely to
* choose the most efficient path, which is all for the best.
*/
extern Path *
GetExistingLocalJoinPath(RelOptInfo *joinrel)
{
ListCell *lc;
- Assert(joinrel->reloptkind == RELOPT_JOINREL);
+ Assert(IS_JOIN_REL(joinrel));
foreach(lc, joinrel->pathlist)
{
Path *path = (Path *) lfirst(lc);
JoinPath *joinpath = NULL;
/* Skip parameterised paths. */
if (path->param_info != NULL)
continue;
@@ -779,27 +779,27 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
* If either inner or outer path is a ForeignPath corresponding to a
* pushed down join, replace it with the fdw_outerpath, so that we
* maintain path for EPQ checks built entirely of local join
* strategies.
*/
if (IsA(joinpath->outerjoinpath, ForeignPath))
{
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->outerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->outerjoinpath = foreign_path->fdw_outerpath;
}
if (IsA(joinpath->innerjoinpath, ForeignPath))
{
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->innerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->innerjoinpath = foreign_path->fdw_outerpath;
}
return (Path *) joinpath;
}
return NULL;
}
diff --git a/src/backend/optimizer/README b/src/backend/optimizer/README
index 775bcc3..29f2bb1 100644
--- a/src/backend/optimizer/README
+++ b/src/backend/optimizer/README
@@ -967,10 +967,51 @@ beneath a Gather node - which we call "partial" paths since they return
only a subset of the results in each worker - must be kept separate from
ordinary paths (see RelOptInfo's partial_pathlist and the function
add_partial_path).
One of the keys to making parallel query effective is to run as much of
the query in parallel as possible. Therefore, we expect it to generally
be desirable to postpone the Gather stage until as near to the top of the
plan as possible. Expanding the range of cases in which more work can be
pushed below the Gather (and costing them accurately) is likely to keep us
busy for a long time to come.
+
+Partition-wise joins
+--------------------
+A join between two similarly partitioned tables can be broken down into joins
+between their matching partitions if there exists an equi-join condition
+between the partition keys of the joining tables. The equi-join between
+partition keys implies that for a given row in a given partition of a given
+partitioned table, its joining row, if exists, should exist only in the
+matching partition of the other partitioned table; no row from non-matching
+partitions in the other partitioned table can join with the given row from the
+first table. This condition allows the join between partitioned table to be
+broken into joins between the matching partitions. The resultant join is
+partitioned in the same way as the joining relations, thus allowing an N-way
+join between similarly partitioned tables having equi-join condition between
+their partition keys to be broken down into N-way joins between their matching
+partitions. This technique of breaking down a join between partition tables
+into join between their partitions is called partition-wise join. We will use
+term "partitioned relation" for both partitioned table as well as join between
+partitioned tables which can use partition-wise join technique.
+
+Partitioning properties of a partitioned table are stored in
+PartitionSchemeData structure. Planner maintains a list of canonical partition
+schemes (distinct PartitionSchemeData objects) so that any two partitioned
+relations with same partitioning scheme share the same PartitionSchemeData
+object. This reduces memory consumed by PartitionSchemeData objects and makes
+it easy to compare the partition schemes of joining relations. RelOptInfos of
+partitioned relations hold partition key expressions and the RelOptInfos of
+the partition relations of that relation.
+
+Partition-wise joins are planned in two phases
+
+1. First phase creates the RelOptInfos for joins between matching partitions
+and creates join paths for these joins. The join paths for join between
+partitions are created using the same techniques as described above.
+
+2. After creating all possible paths for joins between the partitions,
+Append/MergeAppend paths are created to construct join between the partitioned
+relations by choosing the one path from each of the RelOptInfos created
+in the first phase. Append/Merge append paths with different possible
+parameterizations and pathkeys are created based on the paths created for joins
+between partitions.
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 99b6bc8..ee737f2 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -11,22 +11,24 @@
* src/backend/optimizer/path/allpaths.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include <limits.h>
#include <math.h>
+#include "miscadmin.h"
#include "access/sysattr.h"
#include "access/tsmapi.h"
+#include "catalog/partition.h"
#include "catalog/pg_class.h"
#include "catalog/pg_operator.h"
#include "catalog/pg_proc.h"
#include "foreign/fdwapi.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#ifdef OPTIMIZER_DEBUG
#include "nodes/print.h"
#endif
#include "optimizer/clauses.h"
@@ -37,20 +39,21 @@
#include "optimizer/plancat.h"
#include "optimizer/planner.h"
#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "rewrite/rewriteManip.h"
#include "utils/lsyscache.h"
+#include "utils/rel.h"
/* results of subquery_is_pushdown_safe */
typedef struct pushdown_safety_info
{
bool *unsafeColumns; /* which output columns are unsafe to use */
bool unsafeVolatile; /* don't push down volatile quals */
bool unsafeLeaky; /* don't push down leaky quals */
} pushdown_safety_info;
@@ -119,20 +122,24 @@ static void check_output_expressions(Query *subquery,
static void compare_tlist_datatypes(List *tlist, List *colTypes,
pushdown_safety_info *safetyInfo);
static bool targetIsInAllPartitionLists(TargetEntry *tle, Query *query);
static bool qual_is_pushdown_safe(Query *subquery, Index rti, Node *qual,
pushdown_safety_info *safetyInfo);
static void subquery_push_qual(Query *subquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels);
+static void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
/*
* make_one_rel
* Finds all possible access paths for executing a query, returning a
* single rel that represents the join of all base rels in the query.
*/
RelOptInfo *
make_one_rel(PlannerInfo *root, List *joinlist)
{
@@ -861,20 +868,44 @@ static void
set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte)
{
int parentRTindex = rti;
bool has_live_children;
double parent_rows;
double parent_size;
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ Oid *part_oids = NULL;
+ int nparts = 0;
+
+ /* Fetch the number of partitions of a partitioned table and their Oids. */
+ if (rel->part_scheme)
+ {
+ RangeTblEntry *rte = root->simple_rte_array[rel->relid];
+
+ /*
+ * We need not lock the relation since it was already locked, either by
+ * the rewriter or when expand_inherited_rtentry() added it to the
+ * query's rangetable.
+ */
+ Relation relation = heap_open(rte->relid, NoLock);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+
+ part_oids = part_desc->oids;
+ nparts = part_desc->nparts;
+
+ Assert(part_oids && nparts > 0);
+
+ rel->part_rels = (RelOptInfo **)palloc0(sizeof(RelOptInfo *) * nparts);
+ heap_close(relation, NoLock);
+ }
/*
* Initialize to compute size estimates for whole append relation.
*
* We handle width estimates by weighting the widths of different child
* rels proportionally to their number of rows. This is sensible because
* the use of width estimates is mainly to compute the total relation
* "footprint" if we have to sort or hash it. To do this, we sum the
* total equivalent size (in "double" arithmetic) and then divide by the
* total rowcount estimate. This is done separately for the total rel
@@ -892,35 +923,84 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
List *childquals;
Node *childqual;
ListCell *parentvars;
ListCell *childvars;
+ int cnt_parts;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
/*
* The child rel's RelOptInfo was already created during
* add_base_rels_to_query.
*/
childrel = find_base_rel(root, childRTindex);
+
+ /*
+ * Recursively save topmost parent's relid in RelOptInfos of
+ * partitions.
+ */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
+ /*
+ * For two partitioned tables with the same partitioning scheme, it is
+ * assumed that the Oids of matching partitions from both the tables
+ * are placed at the same position in the array of partition oids in
+ * respective partition descriptors. Saving the RelOptInfo of a
+ * partition in the same location as its Oid makes it easy to find the
+ * RelOptInfos of matching partitions for partition-wise join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+
+ /*
+ * Copy/Modify targetlist. Partition-wise join technique may join this
+ * child with a child of another partitioned table, such that this
+ * child forms the nullable side of the outer join. In such a case, we
+ * will need the targetlist of this child, even if it's deemed empty.
+ * Hence set the targetlist before bailing out in case the child is
+ * proven empty.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ appinfo);
+
/*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
* baserestrictinfo quals are needed before we can check for
* constraint exclusion; so do that first and then check to see if we
* can disregard this child.
*
* As of 8.4, the child rel's targetlist might contain non-Var
* expressions, which means that substitution into the quals could
* produce opportunities for const-simplification, and perhaps even
@@ -953,38 +1033,25 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
if (relation_excluded_by_constraints(root, childrel, childRTE))
{
/*
* This child need not be scanned, so we can omit it from the
* appendrel.
*/
set_dummy_rel_pathlist(childrel);
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying join quals. */
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
appinfo);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo);
/*
* We have to make child entries in the EquivalenceClass data
* structures as well. This is needed either if the parent
* participates in some eclass joins (because we will want to consider
* inner-indexscan joins on the individual children) or if the parent
* has useful pathkeys (because we should try to build MergeAppend
* paths that produce those sort orderings).
*/
if (rel->has_eclass_joins || has_useful_pathkeys(root, rel))
@@ -1073,20 +1140,30 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
if (child_width <= 0)
child_width = get_typavgwidth(exprType(childvar),
exprTypmod(childvar));
Assert(child_width > 0);
parent_attrsizes[pndx] += child_width * childrel->rows;
}
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ if (!rel->part_rels[cnt_parts])
+ elog(ERROR, "could not find the RelOptInfo of a partition with oid %u",
+ part_oids[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
* Save the finished size estimates.
*/
int i;
Assert(parent_rows > 0);
rel->rows = parent_rows;
rel->reltarget->width = rint(parent_size / parent_rows);
@@ -1115,41 +1192,32 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
/*
* set_append_rel_pathlist
* Build access paths for an "append relation"
*/
static void
set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte)
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
- * Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * Generate access paths for each member relation and remember the
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
continue;
/* Re-locate the child RTE and RelOptInfo */
childRTindex = appinfo->child_relid;
childRTE = root->simple_rte_array[childRTindex];
childrel = root->simple_rel_array[childRTindex];
@@ -1170,20 +1238,70 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
/*
* If child is dummy, ignore it.
*/
if (IS_DUMMY_REL(childrel))
continue;
/*
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ /* Add Append/MergeAppend paths to the "append" relation. */
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+/*
+ * add_paths_to_append_rel
+ * Generate Append/MergeAppend paths for given "append" relation. An
+ * "append" relation can be a base parent relation or a join between
+ * partitioned tables.
+ *
+ * The function collects all parameterizations and orderings supported by the
+ * non-dummy children. For every such parameterization or ordering, it creates
+ * an append path collecting one path from each non-dummy child with given
+ * parameterization or ordering. Similarly it collects partial paths from
+ * non-dummy children to create partial append paths.
+ */
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid = true;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (live_childrels == NIL)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
* the unparameterized Append path we are constructing for the parent.
* If not, there's no workable unparameterized path.
*/
if (childrel->cheapest_total_path->param_info == NULL)
subpaths = accumulate_append_subpath(subpaths,
childrel->cheapest_total_path);
else
@@ -2181,27 +2299,34 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Determine all possible pairs of relations to be joined at this
* level, and build paths for making each one from every available
* pair of lower-level relations.
*/
join_search_one_level(root, lev);
/*
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
+ * join_search_one_level. Similarly, create append paths for joinrels
+ * which used partition-wise join technique. We can not do this
+ * earlier because the paths can get added to a relation representing
+ * join between children at multiple times within
* join_search_one_level. After that, we're done creating paths for
* the joinrel, so run set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
rel = (RelOptInfo *) lfirst(lc);
+ /* Create Append/MergeAppend paths for partition-wise joins. */
+ generate_partition_wise_join_paths(root, rel);
+
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
#ifdef OPTIMIZER_DEBUG
debug_print_rel(root, rel);
#endif
}
@@ -2851,20 +2976,92 @@ remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel)
* OK, we don't need it. Replace the expression with a NULL constant.
* Preserve the exposed type of the expression, in case something
* looks at the rowtype of the subquery's result.
*/
tle->expr = (Expr *) makeNullConst(exprType(texpr),
exprTypmod(texpr),
exprCollation(texpr));
}
}
+/*
+ * generate_partition_wise_join_paths
+ * Create appends paths for given join relation, if partition-wise join
+ * technique was used for this join.
+ *
+ * The function collects the non-dummy children and hands them off to
+ * add_paths_to_append_rel(), which does the actual work.
+ *
+ * This must not be called until after we're done creating all paths for the
+ * join between children for specified join between parents. (Otherwise,
+ * add_path might delete a path that some Append/MergeAppend path has a
+ * reference to.)
+ */
+
+static void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *live_children = NIL;
+ int cnt_part;
+
+ /* Handle only join relations. */
+ if (!IS_JOIN_REL(rel))
+ return;
+
+ /*
+ * If partition-wise join technique was not used for any of the join
+ * orders, the join is not partitioned. Reset the partitioning scheme.
+ * TODO: find a condition when some joining order would use partition-wise
+ * join technique and other wouldn't.
+ */
+ if (!rel->part_rels)
+ rel->part_scheme = NULL;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || IS_DUMMY_REL(rel))
+ return;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ for (cnt_part = 0; cnt_part < rel->part_scheme->nparts; cnt_part++)
+ {
+ RelOptInfo *child_rel = rel->part_rels[cnt_part];
+
+ /* Ignore dummy child. */
+ if (!IS_DUMMY_REL(child_rel))
+ {
+ /* Recursively collect the paths from child joinrel. */
+ generate_partition_wise_join_paths(root, child_rel);
+
+ /* Find the cheapest of the paths for this rel. */
+ set_cheapest(child_rel);
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ live_children = lappend(live_children, child_rel);
+ }
+ }
+
+ /*
+ * Create append paths by collecting subpaths from live children. Even if
+ * there are no live children, we should create an append path with no
+ * subpaths i.e. a dummy access path.
+ */
+ add_paths_to_append_rel(root, rel, live_children);
+
+ if (live_children)
+ list_free(live_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
*****************************************************************************/
#ifdef OPTIMIZER_DEBUG
static void
print_relids(PlannerInfo *root, Relids relids)
{
int x;
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 2a49639..a23da1c 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -119,20 +119,21 @@ bool enable_seqscan = true;
bool enable_indexscan = true;
bool enable_indexonlyscan = true;
bool enable_bitmapscan = true;
bool enable_tidscan = true;
bool enable_sort = true;
bool enable_hashagg = true;
bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
typedef struct
{
PlannerInfo *root;
QualCost total;
} cost_qual_eval_context;
static List *extract_nonindex_conditions(List *qual_clauses, List *indexquals);
static MergeScanSelCache *cached_scansel(PlannerInfo *root,
RestrictInfo *rinfo,
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index 0e50ad5..73026a3 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2359,20 +2359,22 @@ eclass_useful_for_merging(PlannerInfo *root,
/*
* Note we don't test ec_broken; if we did, we'd need a separate code path
* to look through ec_sources. Checking the members anyway is OK as a
* possibly-overoptimistic heuristic.
*/
/* If specified rel is a child, we must consider the topmost parent rel */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->top_parent_relids;
else
relids = rel->relids;
/* If rel already includes all members of eclass, no point in searching */
if (bms_is_subset(eclass->ec_relids, relids))
return false;
/* To join, we need a member not in the given rel */
foreach(lc, eclass->ec_members)
{
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index cc7384f..fae15de 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -18,23 +18,33 @@
#include "executor/executor.h"
#include "foreign/fdwapi.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+/*
+ * Paths parameterized by the parent can be considered to be parameterized by
+ * any of its child.
+ */
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void match_unsorted_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
static void consider_parallel_nestloop(PlannerInfo *root,
RelOptInfo *joinrel,
RelOptInfo *outerrel,
RelOptInfo *innerrel,
@@ -125,38 +135,51 @@ add_paths_to_joinrel(PlannerInfo *root,
* directly to the parameter source rel instead of joining to the other
* input rel. (But see allow_star_schema_join().) This restriction
* reduces the number of parameterized paths we have to deal with at
* higher join levels, without compromising the quality of the resulting
* plan. We express the restriction as a Relids set that must overlap the
* parameterization of any proposed join path.
*/
foreach(lc, root->join_info_list)
{
SpecialJoinInfo *sjinfo = (SpecialJoinInfo *) lfirst(lc);
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between child relations, even if there is a SpecialJoinInfo node for
+ * the join between the topmost parents. Hence while calculating Relids
+ * set representing the restriction, consider relids of topmost parent
+ * of partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
/*
* SJ is relevant to this join if we have some part of its RHS
* (possibly not all of it), and haven't yet joined to its LHS. (This
* test is pretty simplistic, but should be sufficient considering the
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_righthand))
+ bms_overlap(joinrelids, sjinfo->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_lefthand));
}
/*
* However, when a LATERAL subquery is involved, there will simply not be
* any paths for the joinrel that aren't parameterized by whatever the
* subquery is parameterized by, unless its parameterization is resolved
* within the joinrel. So we might as well allow additional dependencies
@@ -272,20 +295,38 @@ try_nestloop_path(PlannerInfo *root,
Path *outer_path,
Path *inner_path,
List *pathkeys,
JoinType jointype,
JoinPathExtraData *extra)
{
Relids required_outer;
JoinCostWorkspace workspace;
/*
+ * For a join between child relations, if the inner path is parameterized
+ * by the parent of the outer relation, it can be considered to be
+ * parameterized by the outer relation. We will be able to create a
+ * nestloop join path with inner relation parameterized by the outer
+ * relation by translating the inner path to be parameterized by the outer
+ * child relation.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_by_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
* doesn't like the look of it, which could only happen if the nestloop is
* still parameterized.
*/
required_outer = calc_nestloop_required_outer(outer_path,
inner_path);
if (required_outer &&
((!bms_overlap(required_outer, extra->param_source_rels) &&
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..da8ad83 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -7,38 +7,57 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* src/backend/optimizer/path/joinrels.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
+#include "miscadmin.h"
+#include "catalog/partition.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
static void make_rels_by_clause_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static void make_rels_by_clauseless_joins(PlannerInfo *root,
RelOptInfo *old_rel,
ListCell *other_rels);
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static SpecialJoinInfo * build_child_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1,
+ List *append_rel_infos2);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
/*
* join_search_one_level
* Consider ways to produce join relations containing exactly 'level'
* jointree items. (This is one step of the dynamic-programming method
* embodied in standard_join_search.) Join rel nodes for each feasible
* combination of lower-level rels are created and returned in a list.
* Implementation paths are created for each such joinrel, too.
*
@@ -717,20 +736,44 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
/*
* If we've already proven this join is empty, we needn't consider any
* more paths for it.
*/
if (is_dummy_rel(joinrel))
{
bms_free(joinrelids);
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Add paths joining given input relations to the given joinrel. The
+ * SpecialJoinInfo provides details about the join and the restrictlist
+ * contains the join clauses and the other clauses applicable for given pair
+ * of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
* is provably empty too; in which case throw away any previously computed
* paths and mark the join as dummy. (We do it this way since it's
* conceivable that dummy-ness of a multi-element join might only be
* noticeable for certain construction paths.)
*
* Also, a provably constant-false join restriction typically means that
* we can skip evaluating one or both sides of the join. We do this by
@@ -861,27 +904,22 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
mark_dummy_rel(rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
break;
default:
/* other values not expected here */
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
-
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
* a join-order restriction arising from special or lateral joins.
*
* In practice this is always used with have_relevant_joinclause(), and so
* could be merged with that function, but it seems clearer to separate the
* two concerns. We need this test because there are degenerate cases where
* a clauseless join must be performed to satisfy join-order restrictions.
* Also, if one rel has a lateral reference to the other, or both are needed
@@ -1242,10 +1280,378 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
/* constant NULL is as good as constant FALSE for our purposes */
if (con->constisnull)
return true;
if (!DatumGetBool(con->constvalue))
return true;
}
}
return false;
}
+
+/*
+ * TODO: In addition, the comments for individual comments and chunks of code
+ * need to do a better job explaining how each part of the patch contributes to
+ * the overall picture. Make a distinction between the partition-wise join as a
+ * join performed by breaking down join between partitioned tables and
+ * other-join-rel which is anologous to other-base-rel.
+ */
+
+/*
+ * Assess whether join between given two partitioned relations can be broken
+ * down into joins between matching partitions; a technique called
+ * "partition-wise join"
+ *
+ * Partition-wise join is possible when a. Joining relations have same
+ * partitioning scheme b. There exists an equi-join between the partition keys
+ * of the two relations.
+ *
+ * Partition-wise join is planned in two phases
+ *
+ * 1. Create the RelOptInfos for joins between matching partitions and add join
+ * paths to those. This function is responsible for this phase.
+ *
+ * 2. Add Append/MergeAppend paths to the RelOptInfo representing the join
+ * between the partitioned relations by choosing one path from each of the
+ * RelOptInfos created in the first phase. The second phase is implemented by
+ * generate_partition_wise_join_paths().
+ *
+ * The RelOptInfo, SpecialJoinInfo and restrictlist for each child join are
+ * obtained by translating the respective parent join structures.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ PartitionScheme part_scheme;
+
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If any of the joining relation is proven empty, either the join will be
+ * empty (INNER join) or will have the inner side all nullified. We take
+ * care of such cases when creating join paths for parent relations.
+ * Nothing to be done here. Also, nothing to do, if the join is proven
+ * empty.
+ */
+ if (IS_DUMMY_REL(rel1) || IS_DUMMY_REL(rel2) || IS_DUMMY_REL(joinrel))
+ return;
+
+ /*
+ * Partitioning scheme in join relation indicates a possibilty that the
+ * join may be partitioned, but it's not necessary that every join order
+ * can use partition-wise join technique. If one of joining relations turns
+ * out to be unpartitioned, this pair of joining relations can not use
+ * partition-wise join technique.
+ */
+ if (!rel1->part_scheme || !rel2->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, this pair of joining relations can not use
+ * partition-wise technique.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ /*
+ * The partition scheme of the join relation should match that of the
+ * joining relations.
+ */
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ /* Make sure we have RelOptInfos of the partitions available. */
+ Assert(rel1->part_rels && rel2->part_rels);
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ part_scheme = joinrel->part_scheme;
+ nparts = part_scheme->nparts;
+
+ elog(DEBUG3, "join between relations %s and %s is considered for partition-wise join.",
+ bmsToString(rel1->relids), bmsToString(rel2->relids));
+
+ /* Allocate the array for child RelOptInfos if not done already. */
+ if (!joinrel->part_rels)
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * This joinrel is partitioned, so iterate over the partitions and create
+ * paths for each one, allowing us to eventually build an append-of-joins
+ * path for the parent. Since this routine may be called multiple times
+ * for various join orders, the RelOptInfo needed for each child join may
+ * or may not already exist, but the paths for this join order definitely
+ * do not. Note that we don't create any actual AppendPath at this stage;
+ * it only makes sense to do that at the end, after each possible join
+ * order has been considered for each child join. The best join order may
+ * differ from child to child.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_joinrel;
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ List *join_appinfos;
+ List *appinfos1;
+ List *appinfos2;
+
+ /* We should have a valid RelOptInfo for partitions being joined. */
+ Assert(child_rel1 && child_rel2);
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ appinfos1 = find_appinfos_by_relids(root, child_rel1->relids);
+ appinfos2 = find_appinfos_by_relids(root, child_rel2->relids);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, parent_sjinfo,
+ appinfos1, appinfos2);
+
+ /* Construct the parent-child relid map for the join relation. */
+ join_appinfos = list_concat(appinfos1, appinfos2);
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = (List *) adjust_join_appendrel_attrs(root,
+ (Node *)parent_restrictlist,
+ join_appinfos);
+
+ child_joinrel = joinrel->part_rels[cnt_parts];
+
+ /* Construct the join relation for given partition of the join. */
+ if (!child_joinrel)
+ {
+ child_joinrel = build_child_join_rel(root, child_rel1,
+ child_rel2, joinrel,
+ child_sjinfo,
+ child_restrictlist,
+ join_appinfos);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ }
+
+ /*
+ * If we've already proven that this join is empty, we needn't consider
+ * any more paths for it.
+ */
+ if (is_dummy_rel(child_joinrel))
+ continue;
+
+ populate_joinrel_with_paths(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the child relations themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+ }
+}
+
+/*
+ * Construct the SpecialJoinInfo for the join between children by translating
+ * SpecialJoinInfo for the join between parents.
+ */
+static SpecialJoinInfo *
+build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1, List *append_rel_infos2)
+{
+ SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo);
+
+ sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
+ append_rel_infos1);
+ sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
+ append_rel_infos2);
+ sjinfo->syn_lefthand = adjust_child_relids(sjinfo->syn_lefthand,
+ append_rel_infos1);
+ sjinfo->syn_righthand = adjust_child_relids(sjinfo->syn_righthand,
+ append_rel_infos2);
+
+ /* Replace the Var nodes of parent with those of children in expressions. */
+ sjinfo->semi_rhs_exprs = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ append_rel_infos2);
+ return sjinfo;
+}
+
+/*
+ * Replace parent relids by child relids in the given relid set.
+ */
+Relids
+adjust_child_relids(Relids relids, List *append_rel_infos)
+{
+ ListCell *lc;
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ /* Remove parent, add child*/
+ if (bms_is_member(appinfo->parent_relid, relids))
+ {
+ relids = bms_del_member(relids, appinfo->parent_relid);
+ relids = bms_add_member(relids, appinfo->child_relid);
+ }
+ }
+ return relids;
+}
+
+/*
+ * Returns true if there exists an equi-join condition for each pair of
+ * partition key from given relations being joined.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ /*
+ * This function should be called when the joining relations have same
+ * partitioning scheme.
+ */
+ Assert(rel1->part_scheme == rel2->part_scheme);
+ Assert(part_scheme);
+
+ num_pks = part_scheme->partnatts;
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip clauses which can not be used for a join. */
+ if (!rinfo->can_join)
+ continue;
+
+ /* Skip clauses which are not equality conditions. */
+ if (rinfo->hashjoinoperator == InvalidOid && !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+
+ /* Match the operands to the relation. */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ /*
+ * If the clause refers to different partition keys from
+ * both relations, it can not be used for partition-wise join.
+ */
+ if (ipk1 != ipk2)
+ continue;
+
+ /*
+ * The clause allows partition-wise join if only it uses the same
+ * operator family as that specified by the partition key.
+ */
+ if (!list_member_oid(rinfo->mergeopfamilies,
+ part_scheme->partopfamily[ipk1]))
+ continue;
+
+ /* Mark the partition key as having an equi-join clause. */
+ pk_has_clause[ipk1] = true;
+ }
+
+ /* Check whether every partition key has an equi-join condition. */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * Find the partition key from the given relation matching the given
+ * expression. If found, return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks;
+
+ /* This function should be called only for partitioned relations. */
+ Assert(rel->part_scheme);
+
+ num_pks = rel->part_scheme->partnatts;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() simplifies multiple
+ * RelabelType nodes into one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/path/pathkeys.c b/src/backend/optimizer/path/pathkeys.c
index 4436ac1..6996590 100644
--- a/src/backend/optimizer/path/pathkeys.c
+++ b/src/backend/optimizer/path/pathkeys.c
@@ -1081,26 +1081,38 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
RelOptInfo *joinrel)
{
List *pathkeys = NIL;
int nClauses = list_length(mergeclauses);
EquivalenceClass **ecs;
int *scores;
int necs;
ListCell *lc;
int j;
+ Relids relids;
/* Might have no mergeclauses */
if (nClauses == 0)
return NIL;
/*
+ * For a child join relation, use parent relids to find potential
+ * join partners from equivalence classes. A potential join partner of
+ * parent also indicates potential join partner of the child. By using
+ * parent relids we eliminate duplicates arising out of many children.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
+ /*
* Make arrays of the ECs used by the mergeclauses (dropping any
* duplicates) and their "popularity" scores.
*/
ecs = (EquivalenceClass **) palloc(nClauses * sizeof(EquivalenceClass *));
scores = (int *) palloc(nClauses * sizeof(int));
necs = 0;
foreach(lc, mergeclauses)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
@@ -1126,21 +1138,21 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
continue;
/* compute score */
score = 0;
foreach(lc2, oeclass->ec_members)
{
EquivalenceMember *em = (EquivalenceMember *) lfirst(lc2);
/* Potential future join partner? */
if (!em->em_is_const && !em->em_is_child &&
- !bms_overlap(em->em_relids, joinrel->relids))
+ !bms_overlap(em->em_relids, relids))
score++;
}
ecs[necs] = oeclass;
scores[necs] = score;
necs++;
}
/*
* Find out if we have all the ECs mentioned in query_pathkeys; if so we
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 32f4031..b221e2c 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -235,21 +235,22 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
const AttrNumber *reqColIdx,
bool adjust_tlist_in_place,
int *p_numsortkeys,
AttrNumber **p_sortColIdx,
Oid **p_sortOperators,
Oid **p_collations,
bool **p_nullsFirst);
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
static Material *make_material(Plan *lefttree);
static WindowAgg *make_windowagg(List *tlist, Index winref,
int partNumCols, AttrNumber *partColIdx, Oid *partOperators,
int ordNumCols, AttrNumber *ordColIdx, Oid *ordOperators,
int frameOptions, Node *startOffset, Node *endOffset,
Plan *lefttree);
static Group *make_group(List *tlist, List *qual, int numGroupCols,
@@ -1507,21 +1508,21 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
Plan *subplan;
/*
* We don't want any excess columns in the sorted tuples, so request a
* smaller tlist. Otherwise, since Sort doesn't project, tlist
* requirements pass through.
*/
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
return plan;
}
/*
* create_group_plan
*
* Create a Group plan for 'best_path' and (recursively) plans
@@ -3517,31 +3518,33 @@ create_mergejoin_plan(PlannerInfo *root,
List *innerpathkeys;
int nClauses;
Oid *mergefamilies;
Oid *mergecollations;
int *mergestrategies;
bool *mergenullsfirst;
int i;
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
* inputs. However, if we're intending to sort an input's result, it's
* best to request a small tlist so we aren't sorting more data than
* necessary.
*/
- outer_plan = create_plan_recurse(root, best_path->jpath.outerjoinpath,
+ outer_plan = create_plan_recurse(root, outer_path,
(best_path->outersortkeys != NIL) ? CP_SMALL_TLIST : 0);
- inner_plan = create_plan_recurse(root, best_path->jpath.innerjoinpath,
+ inner_plan = create_plan_recurse(root, inner_path,
(best_path->innersortkeys != NIL) ? CP_SMALL_TLIST : 0);
/* Sort join qual clauses into best execution order */
/* NB: do NOT reorder the mergeclauses */
joinclauses = order_qual_clauses(root, best_path->jpath.joinrestrictinfo);
/* Get the join qual clauses (in plain expression form) */
/* Any pseudoconstant clauses are ignored here */
if (IS_OUTER_JOIN(best_path->jpath.jointype))
{
@@ -3573,48 +3576,52 @@ create_mergejoin_plan(PlannerInfo *root,
otherclauses = (List *)
replace_nestloop_params(root, (Node *) otherclauses);
}
/*
* Rearrange mergeclauses, if needed, so that the outer variable is always
* on the left; mark the mergeclause restrictinfos with correct
* outer_is_left status.
*/
mergeclauses = get_switched_clauses(best_path->path_mergeclauses,
- best_path->jpath.outerjoinpath->parent->relids);
+ outer_path->parent->relids);
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
outerpathkeys = best_path->outersortkeys;
}
else
- outerpathkeys = best_path->jpath.outerjoinpath->pathkeys;
+ outerpathkeys = outer_path->pathkeys;
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
innerpathkeys = best_path->innersortkeys;
}
else
- innerpathkeys = best_path->jpath.innerjoinpath->pathkeys;
+ innerpathkeys = inner_path->pathkeys;
/*
* If specified, add a materialize node to shield the inner plan from the
* need to handle mark/restore.
*/
if (best_path->materialize_inner)
{
Plan *matplan = (Plan *) make_material(inner_plan);
/*
@@ -5330,25 +5337,25 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any
* further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
exprvars = pull_var_clause((Node *) sortexpr,
PVC_INCLUDE_AGGREGATES |
PVC_INCLUDE_WINDOWFUNCS |
PVC_INCLUDE_PLACEHOLDERS);
foreach(k, exprvars)
{
if (!tlist_member_ignore_relabel(lfirst(k), tlist))
@@ -5445,57 +5452,58 @@ find_ec_member_for_tle(EquivalenceClass *ec,
Expr *emexpr;
/*
* We shouldn't be trying to sort by an equivalence class that
* contains a constant, so no need to consider such cases any further.
*/
if (em->em_is_const)
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
emexpr = em->em_expr;
while (emexpr && IsA(emexpr, RelabelType))
emexpr = ((RelabelType *) emexpr)->arg;
if (equal(emexpr, tlexpr))
return em;
}
return NULL;
}
/*
* make_sort_from_pathkeys
* Create sort plan to sort according to given pathkeys
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
Oid *sortOperators;
Oid *collations;
bool *nullsFirst;
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
&sortColIdx,
&sortOperators,
&collations,
&nullsFirst);
/* Now build the Sort node */
return make_sort(lefttree, numsortkeys,
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 193b2c9..6c703b8 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -1873,20 +1873,71 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
appinfo);
}
result = (Node *) newnode;
}
else
result = adjust_appendrel_attrs_mutator(node, &context);
return result;
}
+/*
+ * find_appinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *appinfo_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (bms_is_member(appinfo->child_relid, relids))
+ appinfo_list = lappend(appinfo_list, appinfo);
+ }
+
+ Assert(list_length(appinfo_list) == bms_num_members(relids));
+ return appinfo_list;
+}
+
+/*
+ * adjust_join_appendrel_attrs
+ *
+ * Replace the parent references in the given node by the child references
+ * specified by the list of AppendRelInfo.
+ *
+ * This function is a wrapper around adjust_appendrel_attrs() which handles
+ * only one AppendRelInfo at a time.
+ *
+ * TODO: measure how much memory we are leaking, how does the memory usage grow
+ * for N-way joins between tables having many many partitions with N very
+ * large.
+ */
+
+Node *
+adjust_join_appendrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos)
+{
+ ListCell *lc;
+
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+ node = adjust_appendrel_attrs(root, node, appinfo);
+ }
+
+ return node;
+}
+
static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
AppendRelInfo *appinfo = context->appinfo;
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index abb7507..0463369 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -16,21 +16,23 @@
#include <math.h>
#include "miscadmin.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
#include "utils/selfuncs.h"
typedef enum
{
COSTS_EQUAL, /* path costs are fuzzily equal */
COSTS_BETTER1, /* first path is cheaper than second */
@@ -3202,10 +3204,165 @@ reparameterize_path(PlannerInfo *root, Path *path,
rel,
spath->subpath,
spath->path.pathkeys,
required_outer);
}
default:
break;
}
return NULL;
}
+
+/*
+ * reparameterize_path_by_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ *
+ * The cost, number of rows, width and parallel path properties depend upon
+ * path->parent, which does not change during the translation. Hence those
+ * members are copied as they are.
+ */
+
+Path *
+reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+
+ /*
+ * If the path is not parameterized by parent of the given relation, it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = adjust_child_relids(bms_copy(old_ppi->ppi_req_outer),
+ child_aris);
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) old_ppi->ppi_clauses,
+ child_aris);
+
+ /* Adjust the path target. */
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ new_path->param_info = new_ppi;
+
+ /*
+ * Change parameterization of subpaths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_by_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_by_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_by_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexquals = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) ipath->indexquals,
+ child_aris);
+ ipath->indexquals = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) ipath->indexorderbys,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index f8bfa4b..a0e17d5 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -404,20 +404,35 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
}
else
{
rel->serverid = InvalidOid;
rel->fdwroutine = NULL;
}
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation);
+ /*
+ * Lookup partition scheme for the given relation. Only parent relations
+ * can be partitioned.
+ */
+ if (inhparent)
+ rel->part_scheme = find_partition_scheme(root, relation);
+ else
+ rel->part_scheme = NULL;
+
+ if (rel->part_scheme)
+ rel->partexprs = build_baserel_partition_key_exprs(relation,
+ rel->relid);
+ else
+ rel->partexprs = NULL;
+
heap_close(relation, NoLock);
/*
* Allow a plugin to editorialize on the info we obtained from the
* catalogs. Actions might include altering the assumed relation size,
* removing an index, or adding a hypothetical index to the indexlist.
*/
if (get_relation_info_hook)
(*get_relation_info_hook) (root, relationObjectId, inhparent, rel);
}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index deef560..93275b4 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -8,29 +8,35 @@
*
*
* IDENTIFICATION
* src/backend/optimizer/util/relnode.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
+#include "catalog/partition.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
+#include "nodes/makefuncs.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
{
Relids join_relids; /* hash key --- MUST BE FIRST */
RelOptInfo *join_rel;
} JoinHashEntry;
static void build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel);
@@ -40,20 +46,25 @@ static List *build_joinrel_restrictlist(PlannerInfo *root,
RelOptInfo *inner_rel);
static void build_joinrel_joinlist(RelOptInfo *joinrel,
RelOptInfo *outer_rel,
RelOptInfo *inner_rel);
static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_restrictlist);
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
/*
* setup_simple_rel_arrays
* Prepare the arrays we use for quickly accessing base relations.
*/
void
setup_simple_rel_arrays(PlannerInfo *root)
{
Index rti;
@@ -130,20 +141,24 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
rel->serverid = InvalidOid;
rel->userid = rte->checkAsUser;
rel->useridiscurrent = false;
rel->fdwroutine = NULL;
rel->fdw_private = NULL;
rel->baserestrictinfo = NIL;
rel->baserestrictcost.startup = 0;
rel->baserestrictcost.per_tuple = 0;
rel->joininfo = NIL;
rel->has_eclass_joins = false;
+ rel->part_scheme = NULL;
+ rel->partexprs = NULL;
+ rel->top_parent_relids = NULL;
+ rel->part_rels = NULL;
/* Check type of rtable entry */
switch (rte->rtekind)
{
case RTE_RELATION:
/* Table --- retrieve statistics from the system catalogs */
get_relation_info(root, rte->relid, rte->inh, rel);
break;
case RTE_SUBQUERY:
case RTE_FUNCTION:
@@ -307,20 +322,70 @@ find_join_rel(PlannerInfo *root, Relids relids)
if (bms_equal(rel->relids, relids))
return rel;
}
}
return NULL;
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
*
* 'joinrelids' is the Relids set that uniquely identifies the join
* 'outer_rel' and 'inner_rel' are relation nodes for the relations to be
* joined
* 'sjinfo': join context info
* 'restrictlist_ptr': result variable. If not NULL, *restrictlist_ptr
* receives the list of RestrictInfo nodes that apply to this
@@ -356,21 +421,25 @@ build_join_rel(PlannerInfo *root,
joinrel,
outer_rel,
inner_rel);
return joinrel;
}
/*
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
+
+ Assert(!IS_OTHER_REL(outer_rel->reloptkind) &&
+ !IS_OTHER_REL(inner_rel->reloptkind));
joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
joinrel->consider_startup = (root->tuple_fraction > 0);
joinrel->consider_param_startup = false;
joinrel->consider_parallel = false;
joinrel->reltarget = create_empty_pathtarget();
joinrel->pathlist = NIL;
joinrel->ppilist = NIL;
joinrel->partial_pathlist = NIL;
@@ -402,61 +471,27 @@ build_join_rel(PlannerInfo *root,
joinrel->serverid = InvalidOid;
joinrel->userid = InvalidOid;
joinrel->useridiscurrent = false;
joinrel->fdwroutine = NULL;
joinrel->fdw_private = NULL;
joinrel->baserestrictinfo = NIL;
joinrel->baserestrictcost.startup = 0;
joinrel->baserestrictcost.per_tuple = 0;
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Compute information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
* this join (ie, are needed for higher joinclauses or final output).
*
* NOTE: the tlist order for a join rel will depend on which pair of outer
* and inner rels we first try to build it from. But the contents should
* be the same regardless.
*/
build_joinrel_tlist(root, joinrel, outer_rel);
@@ -468,20 +503,24 @@ build_join_rel(PlannerInfo *root,
* sets of any PlaceHolderVars computed here to direct_lateral_relids, so
* now we can finish computing that. This is much like the computation of
* the transitively-closed lateral_relids in min_join_parameterization,
* except that here we *do* have to consider the added PHVs.
*/
joinrel->direct_lateral_relids =
bms_del_members(joinrel->direct_lateral_relids, joinrel->relids);
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
* for set_joinrel_size_estimates().)
*/
restrictlist = build_joinrel_restrictlist(root, joinrel,
outer_rel, inner_rel);
if (restrictlist_ptr)
*restrictlist_ptr = restrictlist;
build_joinrel_joinlist(joinrel, outer_rel, inner_rel);
@@ -510,58 +549,168 @@ build_join_rel(PlannerInfo *root,
* assume this doesn't matter, because we should hit all the same baserels
* and joinclauses while building up to this joinrel no matter which we
* take; therefore, we should make the same decision here however we get
* here.
*/
if (inner_rel->consider_parallel && outer_rel->consider_parallel &&
is_parallel_safe(root, (Node *) restrictlist) &&
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the query's PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
* to the appropriate sublist. Note: you might think the Assert on number
* of members should be for equality, but some of the level 1 rels might
* have been joinrels already, so we can only assert <=.
*/
if (root->join_rel_level)
{
Assert(root->join_cur_level > 0);
Assert(root->join_cur_level <= bms_num_members(joinrel->relids));
root->join_rel_level[root->join_cur_level] =
lappend(root->join_rel_level[root->join_cur_level], joinrel);
}
return joinrel;
}
/*
+ * build_child_join_rel
+ * Builds RelOptInfo for joining given two child relations from RelOptInfo
+ * representing the join between their parents.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of child relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for child join
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_appinfos': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist,
+ List *join_appinfos)
+{
+ List *tmp_exprs;
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel->reloptkind) &&
+ IS_OTHER_REL(inner_rel->reloptkind));
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Compute information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /* Translate targetlist and joininfo. */
+ joinrel->reltarget = copy_pathtarget(parent_joinrel->reltarget);
+ tmp_exprs = joinrel->reltarget->exprs;
+ joinrel->reltarget->exprs = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) tmp_exprs,
+ join_appinfos);
+ joinrel->joininfo = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) parent_joinrel->joininfo,
+ join_appinfos);
+
+
+ /*
+ * Lateral relids referred in child join will be same as that referred in
+ * the parent relation.
+ */
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, sjinfo->jointype);
+
+ /*
+ * Set estimates of the joinrel's size.
+ */
+ set_joinrel_size_estimates(root, joinrel, outer_rel, inner_rel, sjinfo,
+ restrictlist);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ /* We build the join only once. */
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
+/*
* min_join_parameterization
*
* Determine the minimum possible parameterization of a joinrel, that is, the
* set of other rels it contains LATERAL references to. We save this value in
* the join's RelOptInfo. This function is split out of build_join_rel()
* because join_is_legal() needs the value to check a prospective join.
*/
Relids
min_join_parameterization(PlannerInfo *root,
Relids joinrelids,
@@ -1313,10 +1462,118 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
ppi->ppi_req_outer = required_outer;
ppi->ppi_rows = 0;
ppi->ppi_clauses = NIL;
appendrel->ppilist = lappend(appendrel->ppilist, ppi);
return ppi;
}
+
+/*
+ * add_join_rel
+ * Add given join relation to the list of join relations in the given
+ * PlannerInfo. Also add it to the auxiliary hashtable if there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
+ * build_joinrel_partition_info
+ * If the join between given partitioned relations is possibly partitioned
+ * set the partitioning scheme and partition keys expressions for the
+ * join.
+ *
+ * If the two relations have same partitioning scheme, their join may be
+ * partitioned and will follow the same partitioning scheme as the joining
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /* Nothing to do if partition-wise join technique is disabled. */
+ if (!enable_partition_wise_join)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * The join is not partitioned, if any of the relations being joined are
+ * not partitioned or they do not have same partitioning scheme.
+ */
+ if (!outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel, hence it should
+ * not have partition scheme, partition key expressions and array for
+ * storing child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ /*
+ * Join relation is partitioned using same partitioning scheme as the
+ * joining relations.
+ */
+ joinrel->part_scheme = outer_rel->part_scheme;
+ num_pks = joinrel->part_scheme->partnatts;
+
+ /*
+ * Construct partition keys for the join.
+ *
+ * An INNER join between two partitioned relations is partition by key
+ * expressions from both the relations. For tables A and B partitioned by a and b
+ * respectively, (A INNER JOIN B ON A.a = B.b) is partitioned by both A.a
+ * and B.b.
+ *
+ * An OUTER join like (A LEFT JOIN B ON A.a = B.b) may produce rows with
+ * B.b NULL. These rows may not fit the partitioning conditions imposed on
+ * B.b. Hence, strictly speaking, the join is not partitioned by B.b.
+ * Strictly speaking, partition keys of an OUTER join should include
+ * partition key expressions from the OUTER side only. Consider a join like
+ * (A LEFT JOIN B on (A.a = B.b) LEFT JOIN C ON B.b = C.c. If we do not
+ * include B.b as partition key expression for (AB), it prohibits us from
+ * using partition-wise join when joining (AB) with C as there is no
+ * equi-join between partition keys of joining relations. But two NULL
+ * values are never equal and no two rows from mis-matching partitions can
+ * join. Hence it's safe to include B.b as partition key expression for
+ * (AB), even though rows in (AB) are not strictly partitioned by B.b.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 56943f2..16b2eac 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3405,21 +3405,23 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
else
{
/* not time to process varinfo2 yet */
newvarinfos = lcons(varinfo2, newvarinfos);
}
}
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
if (rel->tuples > 0)
{
/*
* Clamp to size of rel, or size of rel / 10 if multiple Vars. The
* fudge factor is because the Vars are probably correlated but we
* don't know by how much. We should never clamp to less than the
* largest ndistinct value for any of the Vars, though, since
* there will surely be at least that many groups.
*/
double clamp = rel->tuples;
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index ce4eef9..edc7e58 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -870,20 +870,29 @@ static struct config_bool ConfigureNamesBool[] =
},
{
{"enable_hashjoin", PGC_USERSET, QUERY_TUNING_METHOD,
gettext_noop("Enables the planner's use of hash join plans."),
NULL
},
&enable_hashjoin,
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
gettext_noop("Enables genetic query optimization."),
gettext_noop("This algorithm attempts to do planning without "
"exhaustive searching.")
},
&enable_geqo,
true,
NULL, NULL, NULL
diff --git a/src/include/catalog/partition.h b/src/include/catalog/partition.h
index 81a4b91..19b7744 100644
--- a/src/include/catalog/partition.h
+++ b/src/include/catalog/partition.h
@@ -39,22 +39,57 @@ typedef struct BoundCollectionData *BoundCollection;
* is list partitioned. Whereas in case of a range partitioned table, they
* are ordered to match the ascending order of partition ranges.
*/
typedef struct PartitionDescData
{
int nparts; /* Number of partitions */
Oid *oids; /* OIDs of partitions */
BoundCollection bounds; /* collection of list or range bounds */
} PartitionDescData;
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting may be partitioned in the same way as the underlying
+ * scan relations. All such relations partitioned in the same way share the
+ * partitioning scheme.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ BoundCollection bounds; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
typedef struct PartitionDescData *PartitionDesc;
typedef struct PartitionTreeNodeData *PartitionTreeNode;
+typedef struct PartitionSchemeData *PartitionScheme;
+
+/* Include here to avoid circular dependency with relation.h. */
+struct PlannerInfo;
/* relcache support for partition key information */
extern void RelationBuildPartitionKey(Relation relation);
/* Partition key inquiry functions */
extern int get_partition_key_strategy(PartitionKey key);
extern int get_partition_key_natts(PartitionKey key);
extern List *get_partition_key_exprs(PartitionKey key);
/* Partition key inquiry functions - for a given column */
@@ -77,11 +112,16 @@ extern List *get_qual_from_partbound(Relation rel, Relation parent, Node *bound)
extern List *RelationGetPartitionQual(Relation rel, bool recurse);
/* For tuple routing */
extern PartitionTreeNode RelationGetPartitionTreeNode(Relation rel);
extern List *get_leaf_partition_oids_v2(PartitionTreeNode ptnode);
extern int get_partition_for_tuple(PartitionTreeNode ptnode,
TupleTableSlot *slot,
EState *estate,
Oid *failed_at);
+extern List **build_baserel_partition_key_exprs(Relation relation,
+ Index varno);
+extern PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+
#endif /* PARTITION_H */
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 3a1255a..e79fb09 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -8,20 +8,21 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* src/include/nodes/relation.h
*
*-------------------------------------------------------------------------
*/
#ifndef RELATION_H
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "storage/block.h"
/*
* Relids
* Set of relation identifiers (indexes into the rangetable).
*/
@@ -256,20 +257,23 @@ typedef struct PlannerInfo
List *query_pathkeys; /* desired pathkeys for query_planner() */
List *group_pathkeys; /* groupClause pathkeys, if any */
List *window_pathkeys; /* pathkeys of bottom window, if any */
List *distinct_pathkeys; /* distinctClause pathkeys, if any */
List *sort_pathkeys; /* sortClause pathkeys, if any */
List *initial_rels; /* RelOptInfos we are now trying to join */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
/* Use fetch_upper_rel() to get any particular upper rel */
List *upper_rels[UPPERREL_FINAL + 1]; /* upper-rel RelOptInfos */
/* Result tlists chosen by grouping_planner for upper-stage processing */
struct PathTarget *upper_targets[UPPERREL_FINAL + 1];
/*
* grouping_planner passes back its final processed targetlist here, for
* use in relabeling the topmost tlist of the finished Plan.
*/
@@ -345,20 +349,25 @@ typedef struct PlannerInfo
* is present in the query join tree but the members are not. The member
* RTEs and otherrels are used to plan the scans of the individual tables or
* subqueries of the append set; then the parent baserel is given Append
* and/or MergeAppend paths comprising the best paths for the individual
* member rels. (See comments for AppendRelInfo for more information.)
*
* At one time we also made otherrels to represent join RTEs, for use in
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing joins between child relations of
+ * different partitioned tables. These relations are not added to
+ * join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
* fields always hold Paths showing ways to do that processing step.
*
* Lastly, there is a RelOptKind for "dead" relations, which are base rels
* that we have proven we don't need to join after all.
*
* Parts of this data structure are specific to various scan and join
* mechanisms. It didn't seem worth creating new node types for them.
@@ -464,24 +473,33 @@ typedef struct PlannerInfo
* We store baserestrictcost in the RelOptInfo (for base relations) because
* we know we will need it at least once (to price the sequential scan)
* and may need it multiple times to price index scans.
*----------
*/
typedef enum RelOptKind
{
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(reloptkind) \
+ ((reloptkind) == RELOPT_OTHER_MEMBER_REL || \
+ (reloptkind) == RELOPT_OTHER_JOINREL)
+
+#define IS_JOIN_REL(rel) \
+ ((rel->reloptkind) == RELOPT_JOINREL || \
+ (rel->reloptkind) == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
RelOptKind reloptkind;
/* all relations included in this RelOptInfo */
Relids relids; /* set of base relids (rangetable indexes) */
/* size estimates generated by planner */
@@ -535,20 +553,37 @@ typedef struct RelOptInfo
struct FdwRoutine *fdwroutine;
void *fdw_private;
/* used by various scans and joins: */
List *baserestrictinfo; /* RestrictInfo structures (if base
* rel) */
QualCost baserestrictcost; /* cost of evaluating the above */
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there may be as many elements
+ * as the number of joining
+ * relations.
+ */
+
+ /* Set only for "other" base or join relations. */
+ Relids top_parent_relids; /* Relids of topmost parents. */
} RelOptInfo;
/*
* IndexOptInfo
* Per-index information for planning/optimization
*
* indexkeys[], indexcollations[], opfamily[], and opcintype[]
* each have ncolumns entries.
*
* sortopfamily[], reverse_sort[], and nulls_first[] likewise have
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..1069726 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -59,20 +59,21 @@ extern bool enable_seqscan;
extern bool enable_indexscan;
extern bool enable_indexonlyscan;
extern bool enable_bitmapscan;
extern bool enable_tidscan;
extern bool enable_sort;
extern bool enable_hashagg;
extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
double index_pages, PlannerInfo *root);
extern void cost_seqscan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_samplescan(Path *path, PlannerInfo *root, RelOptInfo *baserel,
ParamPathInfo *param_info);
extern void cost_index(IndexPath *path, PlannerInfo *root,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 71d9154..3c2a72e 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -222,20 +222,22 @@ extern ModifyTablePath *create_modifytable_path(PlannerInfo *root,
List *rowMarks, OnConflictExpr *onconflict,
int epqParam);
extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
*/
extern void setup_simple_rel_arrays(PlannerInfo *root);
extern RelOptInfo *build_simple_rel(PlannerInfo *root, int relid,
RelOptKind reloptkind);
extern RelOptInfo *find_base_rel(PlannerInfo *root, int relid);
extern RelOptInfo *find_join_rel(PlannerInfo *root, Relids relids);
extern RelOptInfo *build_join_rel(PlannerInfo *root,
@@ -260,12 +262,17 @@ extern ParamPathInfo *get_baserel_parampathinfo(PlannerInfo *root,
Relids required_outer);
extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
RelOptInfo *joinrel,
Path *outer_path,
Path *inner_path,
SpecialJoinInfo *sjinfo,
Relids required_outer,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, SpecialJoinInfo *sjinfo,
+ List *restrictlist, List *join_appinfos);
+extern void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..e57a166 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -212,11 +212,13 @@ extern List *make_inner_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
List *outer_pathkeys);
extern List *truncate_useless_pathkeys(PlannerInfo *root,
RelOptInfo *rel,
List *pathkeys);
extern bool has_useful_pathkeys(PlannerInfo *root, RelOptInfo *rel);
extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
+
#endif /* PATHS_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index fb35b68..a7f6271 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -21,20 +21,23 @@
/*
* prototypes for prepjointree.c
*/
extern void pull_up_sublinks(PlannerInfo *root);
extern void inline_set_returning_functions(PlannerInfo *root);
extern void pull_up_subqueries(PlannerInfo *root);
extern void flatten_simple_union_all(PlannerInfo *root);
extern void reduce_outer_joins(PlannerInfo *root);
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
+extern Node *adjust_join_appendrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos);
+extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
/*
* prototypes for prepqual.c
*/
extern Node *negate_clause(Node *node);
extern Expr *canonicalize_qual(Expr *qual);
/*
* prototypes for prepsecurity.c
*/
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..b56eba9
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,6663 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (((t1.a + t1.b) / 2) = ((t2.b + t2.a) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: (((t1_1.a + t1_1.b) / 2) = ((t2_1.b + t2_1.a) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: (((t1_2.a + t1_2.b) / 2) = ((t2_2.b + t2_2.a) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Sort Key: prt1_e_p1.a, prt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt2_e_p1.b, prt2_e_p1.c
+ Hash Cond: (((prt1_e_p1.a + prt1_e_p1.b) / 2) = ((prt2_e_p1.b + prt2_e_p1.a) / 2))
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.c, prt1_e_p1.b
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ -> Seq Scan on public.prt2_e_p1
+ Output: prt2_e_p1.b, prt2_e_p1.c, prt2_e_p1.a
+ Filter: ((prt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt2_e_p2.b, prt2_e_p2.c
+ Hash Cond: (((prt1_e_p2.a + prt1_e_p2.b) / 2) = ((prt2_e_p2.b + prt2_e_p2.a) / 2))
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.c, prt1_e_p2.b
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ -> Seq Scan on public.prt2_e_p2
+ Output: prt2_e_p2.b, prt2_e_p2.c, prt2_e_p2.a
+ Filter: ((prt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt2_e_p3.b, prt2_e_p3.c
+ Hash Cond: (((prt1_e_p3.a + prt1_e_p3.b) / 2) = ((prt2_e_p3.b + prt2_e_p3.a) / 2))
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.c, prt1_e_p3.b
+ Filter: ((prt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ -> Seq Scan on public.prt2_e_p3
+ Output: prt2_e_p3.b, prt2_e_p3.c, prt2_e_p3.a
+ Filter: ((prt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t2.a, t2.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t2_1.a, t2_1.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t2_2.a, t2_2.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((((t2.b + t2.a) / 2) = t1.a) AND (t2.b = ((t1.a + t1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((((t2_1.b + t2_1.a) / 2) = t1_1.a) AND (t2_1.b = ((t1_1.a + t1_1.b) / 2)))
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((((t2_2.b + t2_2.a) / 2) = t1_2.a) AND (t2_2.b = ((t1_2.a + t1_2.b) / 2)))
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.b = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text) AND ((t1_1.b + t1_1.a) = (t2_1.a + t2_1.b)))
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.b = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text) AND ((t1_2.b + t1_2.a) = (t2_2.a + t2_2.b)))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
+ Hash Cond: ((t1_3.a = t2_3.b) AND (t1_3.b = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text) AND ((t1_3.b + t1_3.a) = (t2_3.a + t2_3.b)))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Hash
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: ((t2_3.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_4.b, t2_4.c, t1_4.a, t1_4.c
+ Hash Cond: ((t1_4.a = t2_4.b) AND (t1_4.b = t2_4.a) AND ((t1_4.c)::text = (t2_4.c)::text) AND ((t1_4.b + t1_4.a) = (t2_4.a + t2_4.b)))
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Hash
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: ((t2_4.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_5.b, t2_5.c, t1_5.a, t1_5.c
+ Hash Cond: ((t1_5.a = t2_5.b) AND (t1_5.b = t2_5.a) AND ((t1_5.c)::text = (t2_5.c)::text) AND ((t1_5.b + t1_5.a) = (t2_5.a + t2_5.b)))
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Hash
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: ((t2_5.b % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Sort Key: prt1_l_p1_p1.a, prt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt2_l_p1_p2.b, prt2_l_p1_p2.c
+ Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.c = t1.c) AND (t2.a = t1.a))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.c = t1_1.c) AND (t2_1.a = t1_1.a))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.c = t1_2.c) AND (t2_2.a = t1_2.a))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, avg(plt2_p1.b), plt2_p1.c
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, sum((25)), avg(plt2_p1.b), plt2_p1.c, avg((50))
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (25), (50)
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c, 25
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c, (50)
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c, 50
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, (25), (50)
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c, 25
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c, (50)
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c, 50
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, (25), (50)
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c, 25
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c, (50)
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c, 50
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (avg(t2.b)), t2.c
+ Sort Key: t1.c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, avg(t2.b), t2.c
+ Group Key: t1.c, t2.c
+ -> Result
+ Output: t1.c, t2.c, t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(20 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Left Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Left Join
+ Output: t1_1.a, t1_1.c, t2.b, t2.c
+ Hash Cond: (t1_1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(a)), c, (sum(t2.b)), t2.c
+ Sort Key: c, t2.c
+ -> HashAggregate
+ Output: sum(a), c, sum(t2.b), t2.c
+ Group Key: c, t2.c
+ -> Result
+ Output: c, t2.c, a, t2.b
+ -> Append
+ -> Hash Left Join
+ Output: t2.b, t2.c, a, c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1.a, t1.c
+ Hash Cond: (t1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (ltrim(t1.c, 'A'::text) = ltrim(t2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (ltrim(t1_1.c, 'A'::text) = ltrim(t2_1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (ltrim(t1_2.c, 'A'::text) = ltrim(t2_2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 150 | A0003 | 150 | A0003
+ 300 | A0006 | 300 | A0006
+ 450 | A0009 | 450 | A0009
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Sort Key: plt1_e_p1.a, plt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Hash Cond: ((plt1_e_p1.a = plt2_e_p1.b) AND (ltrim(plt1_e_p1.c, 'A'::text) = ltrim(plt2_e_p1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ -> Seq Scan on public.plt2_e_p1
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ Filter: ((plt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p2.a, plt1_e_p2.c, plt2_e_p2.b, plt2_e_p2.c
+ Hash Cond: ((plt1_e_p2.a = plt2_e_p2.b) AND (ltrim(plt1_e_p2.c, 'A'::text) = ltrim(plt2_e_p2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ -> Seq Scan on public.plt2_e_p2
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ Filter: ((plt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p3.a, plt1_e_p3.c, plt2_e_p3.b, plt2_e_p3.c
+ Hash Cond: ((plt1_e_p3.a = plt2_e_p3.b) AND (ltrim(plt1_e_p3.c, 'A'::text) = ltrim(plt2_e_p3.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ -> Seq Scan on public.plt2_e_p3
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ Filter: ((plt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((t3.a = t2.b) AND ((ltrim(t3.c, 'A'::text)) = t2.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (ltrim(t3.c, 'A'::text))
+ Sort Key: t3.a, (ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ltrim(t3.c, 'A'::text)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((t3_1.a = t2_1.b) AND ((ltrim(t3_1.c, 'A'::text)) = t2_1.c))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (ltrim(t3_1.c, 'A'::text))
+ Sort Key: t3_1.a, (ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ltrim(t3_1.c, 'A'::text)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((t3_2.a = t2_2.b) AND ((ltrim(t3_2.c, 'A'::text)) = t2_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (ltrim(t3_2.c, 'A'::text))
+ Sort Key: t3_2.a, (ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ltrim(t3_2.c, 'A'::text)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: ((ltrim(t1_6.c, 'A'::text)) = t1_3.c)
+ -> Sort
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Sort Key: (ltrim(t1_6.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_6.c, (ltrim(t1_6.c, 'A'::text))
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Sort
+ Output: t1_3.c
+ Sort Key: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: ((ltrim(t1_7.c, 'A'::text)) = t1_4.c)
+ -> Sort
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Sort Key: (ltrim(t1_7.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_7.c, (ltrim(t1_7.c, 'A'::text))
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Sort
+ Output: t1_4.c
+ Sort Key: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: ((ltrim(t1_8.c, 'A'::text)) = t1_5.c)
+ -> Sort
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Sort Key: (ltrim(t1_8.c, 'A'::text))
+ -> HashAggregate
+ Output: t1_8.c, (ltrim(t1_8.c, 'A'::text))
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+ -> Sort
+ Output: t1_5.c
+ Sort Key: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+(88 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (ltrim(t3.c, 'A'::text) = t2.c)
+ Join Filter: (t2.b = t3.a)
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iplt2_p1_c on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a, t1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Merge Cond: ((t2_1.c = t1_1.c) AND (t2_1.b = t1_1.a))
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.c, t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (ltrim(t3_1.c, 'A'::text) = t2_1.c)
+ Join Filter: (t2_1.b = t3_1.a)
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iplt2_p2_c on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.c, t1_1.a
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Merge Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b, t2_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: (ltrim(t3_2.c, 'A'::text) = t2_2.c)
+ Join Filter: (t2_2.b = t3_2.a)
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iplt2_p3_c on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a, t1_2.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Merge Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = (ltrim(plt1_e_p1.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Merge Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Merge Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Sort
+ Output: plt1_p1.a, plt1_p1.c
+ Sort Key: plt1_p1.a, plt1_p1.c
+ -> Index Scan using iplt1_p1_c on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Sort
+ Output: plt2_p1.b, plt2_p1.c
+ Sort Key: plt2_p1.b, plt2_p1.c
+ -> Index Scan using iplt2_p1_c on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, (ltrim(plt1_e_p1.c, 'A'::text))
+ Sort Key: plt1_e_p1.a, (ltrim(plt1_e_p1.c, 'A'::text))
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c, ltrim(plt1_e_p1.c, 'A'::text)
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Merge Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = (ltrim(plt1_e_p2.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Merge Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Merge Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Sort
+ Output: plt1_p2.a, plt1_p2.c
+ Sort Key: plt1_p2.a, plt1_p2.c
+ -> Index Scan using iplt1_p2_c on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Sort
+ Output: plt2_p2.b, plt2_p2.c
+ Sort Key: plt2_p2.b, plt2_p2.c
+ -> Index Scan using iplt2_p2_c on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, (ltrim(plt1_e_p2.c, 'A'::text))
+ Sort Key: plt1_e_p2.a, (ltrim(plt1_e_p2.c, 'A'::text))
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c, ltrim(plt1_e_p2.c, 'A'::text)
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Merge Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = (ltrim(plt1_e_p3.c, 'A'::text))))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Merge Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Merge Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Sort
+ Output: plt1_p3.a, plt1_p3.c
+ Sort Key: plt1_p3.a, plt1_p3.c
+ -> Index Scan using iplt1_p3_c on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Sort
+ Output: plt2_p3.b, plt2_p3.c
+ Sort Key: plt2_p3.b, plt2_p3.c
+ -> Index Scan using iplt2_p3_c on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Sort
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, (ltrim(plt1_e_p3.c, 'A'::text))
+ Sort Key: plt1_e_p3.a, (ltrim(plt1_e_p3.c, 'A'::text))
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c, ltrim(plt1_e_p3.c, 'A'::text)
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(87 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.c = t1_3.c)
+ -> Index Scan using iplt1_p1_c on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c, t1_6.c
+ -> Merge Semi Join
+ Output: t1_3.c, t1_6.c
+ Merge Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Index Only Scan using iplt2_p1_c on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Materialize
+ Output: t1_6.c
+ -> Index Scan using iplt1_e_p1_c on public.plt1_e_p1 t1_6
+ Output: t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.c = t1_4.c)
+ -> Index Scan using iplt1_p2_c on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c, t1_7.c
+ -> Merge Semi Join
+ Output: t1_4.c, t1_7.c
+ Merge Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Index Only Scan using iplt2_p2_c on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Materialize
+ Output: t1_7.c
+ -> Index Scan using iplt1_e_p2_c on public.plt1_e_p2 t1_7
+ Output: t1_7.c
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.c = t1_5.c)
+ -> Index Scan using iplt1_p3_c on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c, t1_8.c
+ -> Merge Semi Join
+ Output: t1_5.c, t1_8.c
+ Merge Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Index Only Scan using iplt2_p3_c on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Materialize
+ Output: t1_8.c
+ -> Index Scan using iplt1_e_p3_c on public.plt1_e_p3 t1_8
+ Output: t1_8.c
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- negative testcases
+--
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out
index f06cfa4..16e7f56 100644
--- a/src/test/regress/expected/rangefuncs.out
+++ b/src/test/regress/expected/rangefuncs.out
@@ -1,25 +1,26 @@
SELECT name, setting FROM pg_settings WHERE name LIKE 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
CREATE TABLE foo2(fooid int, f2 int);
INSERT INTO foo2 VALUES(1, 11);
INSERT INTO foo2 VALUES(2, 22);
INSERT INTO foo2 VALUES(1, 111);
CREATE FUNCTION foot(int) returns setof foo2 as 'SELECT * FROM foo2 WHERE fooid = $1 ORDER BY f2;' LANGUAGE SQL;
-- function with ORDINALITY
select * from foot(1) with ordinality as z(a,b,ord);
a | b | ord
---+-----+-----
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 8641769..5ad149d 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -93,21 +93,21 @@ test: alter_generic alter_operator misc psql async dbsize misc_functions tsrf
# rules cannot run concurrently with any test that creates a view
test: rules psql_crosstab amutils
# run by itself so it can run parallel workers
test: select_parallel
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
# so keep this parallel group to at most 19 tests
# ----------
test: plancache limit plpgsql copy2 temp domain rangefuncs prepare without_oid conversion truncate alter_table sequence polymorphism rowtypes returning largeobject with xml
# event triggers cannot run concurrently with any test that runs DDL
test: event_trigger
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 835cf35..b4773b8 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -162,10 +162,11 @@ test: truncate
test: alter_table
test: sequence
test: polymorphism
test: rowtypes
test: returning
test: largeobject
test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..fedaff4
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,782 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 RIGHT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 RIGHT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_e WHERE prt2_e.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_e t2 WHERE t2.b % 25 = 0) t2 ON ((t1.a + t1.b)/2 = (t2.b + t2.a)/2) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1, uprt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 LEFT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1, plt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1, uplt2_e t2 WHERE t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 RIGHT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 RIGHT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge join with and without index scan
+CREATE INDEX iplt1_c on plt1(c);
+CREATE INDEX iplt1_p1_c on plt1_p1(c);
+CREATE INDEX iplt1_p2_c on plt1_p2(c);
+CREATE INDEX iplt1_p3_c on plt1_p3(c);
+CREATE INDEX iplt2_c on plt2(c);
+CREATE INDEX iplt2_p1_c on plt2_p1(c);
+CREATE INDEX iplt2_p2_c on plt2_p2(c);
+CREATE INDEX iplt2_p3_c on plt2_p3(c);
+CREATE INDEX iplt1_e_c on plt1_e(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p1_c on plt1_e_p1(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p2_c on plt1_e_p2(ltrim(c, 'A'));
+CREATE INDEX iplt1_e_p3_c on plt1_e_p3(ltrim(c, 'A'));
+
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- negative testcases
+--
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
On Fri, Oct 14, 2016 at 12:37 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
Have you tested the effect of this patch on planner memory consumption
with multi-way joins between tables with many partitions? If you
haven't, you probably should. (Testing runtime would be good, too.)
Does it grow linearly? Quadratically? Exponentially? Minor leaks
don't matter, but if we're generating too much garbage we'll have to
make sure it gets cleaned up soon enough to prevent runaway memory
usage.I tried to check memory usage with various combinations of number of
partitions and number of relations being joined. For higher number of
relations being joined like 10 with 100 partitions, OOM killer kicked
in during the planning phase. I am suspecting
adjust_partitionrel_attrs() (changed that name to
adjust_join_appendrel_attrs() to be in sync with
adjust_appendrel_attrs()) to be the culprit. It copies expression
trees every time for joining two children. That's an exponentially
increasing number as the number of legal joins increases
exponentially. I am still investigating this.
I think the root of this problem is that the existing paths shares a
lot more substructure than the ones created by the new code. Without
a partition-wise join, the incremental memory usage for a joinrel
isn't any different whether the underlying rel is partitioned or not.
If it's partitioned, we'll be pointing to an AppendPath; if not, we'll
be pointing to some kind of Scan. But the join itself creates exactly
the same amount of new stuff regardless of what's underneath it. With
partitionwise join, that ceases to be true. Every joinrel - and the
number of those grows exponentially in the number of baserels, IICU -
needs its own list of paths for every member rel. So if a
non-partition-wise join created X paths, and there are K partitions, a
partition-wise join creates X * K paths. That's a lot.
Although we might be able to save some memory by tightening things up
here and there - for example, right now the planner isn't real smart
about recycling paths that are evicted by add_path(), and there's
probably other wastage as well - I suspect that what this shows is
that the basic design of this patch is not going to be viable.
Intuitively, it's often going to be the case that we want the "same
plan" for every partition-set. That is, if we have A JOIN B ON A.x =
B.x JOIN C ON A.y = B.y, and if A, B, and C are all compatibility
partitioned, then the result should be an Append plan with 100 join
plans under it, and all 100 of those plans should be basically mirror
images of each other. Of course, that's not really right in general:
for example, it could be that A1 is big and A2 is small while B1 is
small and B2 is big, so that the right plan for (A1 JOIN B1) and for
(A2 JOIN B2) are totally different from each other. But in many
practical cases we'll want to end up with a plan of precisely the same
shape for all children, and the current design ignores this, expending
both memory and CPU time to compute essentially-equivalent paths
across all children.
One way of attacking this problem is to gang together partitions which
are equivalent for planning purposes, as discussed in the paper "Join
Optimization Techniques for Partitioned Tables" by Herodotou, Borisov,
and Babu. However, it's not exactly clear how to do this: we could
gang together partitions that have the same index definitions, but the
sizes of the heaps, the sizes of their indexes, and the row counts
will vary from one partition to the next, and any of those things
could cause the plan choice to be different for one partition vs. the
next. We could try to come up with heuristics for when those things
are likely to be true. For example, suppose we compute the set of
partitions such that all joined relations have matching index
definitions on all tables; then, we take the biggest table in the set
and consider all tables more than half that size as part of one gang.
The biggest table becomes the leader and we compute partition-wise
paths for just that partition; the other members of the gang will
eventually get a plan that is of the same shape, but we don't actually
create it that plan until after scan/join planning is concluded.
Another idea is to try to reduce peak memory usage by performing
planning separately for each partition-set. For example, suppose we
decide to do a partition-wise join of A, B, and C. Initially, this
gets represented as a PartitionJoinPath tree, like this:
PartitionJoinPath
-> AppendPath for A
-> PartitionJoinPath
-> AppendPath for B
-> AppendPath for C
Because we haven't created individual join paths for the members, this
doesn't use much memory. Somehow, we come up with a cost for the
PartitionJoinPath; it probably won't be entirely accurate. Once
scan/join planning is concluded, if our final path contains a
PartitionJoinPath, we go back and loop over the partitions. For each
partition, we switch to a new memory context, perform planning, copy
the best path and its substructure back to the parent context, and
then reset the context. In that way, peak memory usage only grows by
about a factor of 2 rather than a factor equal to the partition count,
because we don't need to keep every possibly-useful path for every
partition all at the same time, but rather every possibly-useful path
for a single partition.
Maybe there are other ideas but I have a feeling any way you slice it
this is going to be a lot of work.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Tue, Oct 18, 2016 at 9:09 PM, Robert Haas <robertmhaas@gmail.com> wrote:
On Fri, Oct 14, 2016 at 12:37 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Have you tested the effect of this patch on planner memory consumption
with multi-way joins between tables with many partitions? If you
haven't, you probably should. (Testing runtime would be good, too.)
Does it grow linearly? Quadratically? Exponentially? Minor leaks
don't matter, but if we're generating too much garbage we'll have to
make sure it gets cleaned up soon enough to prevent runaway memory
usage.I tried to check memory usage with various combinations of number of
partitions and number of relations being joined. For higher number of
relations being joined like 10 with 100 partitions, OOM killer kicked
in during the planning phase. I am suspecting
adjust_partitionrel_attrs() (changed that name to
adjust_join_appendrel_attrs() to be in sync with
adjust_appendrel_attrs()) to be the culprit. It copies expression
trees every time for joining two children. That's an exponentially
increasing number as the number of legal joins increases
exponentially. I am still investigating this.I think the root of this problem is that the existing paths shares a
lot more substructure than the ones created by the new code. Without
a partition-wise join, the incremental memory usage for a joinrel
isn't any different whether the underlying rel is partitioned or not.
If it's partitioned, we'll be pointing to an AppendPath; if not, we'll
be pointing to some kind of Scan. But the join itself creates exactly
the same amount of new stuff regardless of what's underneath it. With
partitionwise join, that ceases to be true. Every joinrel - and the
number of those grows exponentially in the number of baserels, IICU -
needs its own list of paths for every member rel. So if a
non-partition-wise join created X paths, and there are K partitions, a
partition-wise join creates X * K paths. That's a lot.Although we might be able to save some memory by tightening things up
here and there - for example, right now the planner isn't real smart
about recycling paths that are evicted by add_path(), and there's
probably other wastage as well - I suspect that what this shows is
that the basic design of this patch is not going to be viable.
Intuitively, it's often going to be the case that we want the "same
plan" for every partition-set. That is, if we have A JOIN B ON A.x =
B.x JOIN C ON A.y = B.y, and if A, B, and C are all compatibility
partitioned, then the result should be an Append plan with 100 join
plans under it, and all 100 of those plans should be basically mirror
images of each other. Of course, that's not really right in general:
for example, it could be that A1 is big and A2 is small while B1 is
small and B2 is big, so that the right plan for (A1 JOIN B1) and for
(A2 JOIN B2) are totally different from each other. But in many
practical cases we'll want to end up with a plan of precisely the same
shape for all children, and the current design ignores this, expending
both memory and CPU time to compute essentially-equivalent paths
across all children.
I think there are going to be two kinds of partitioning use-cases.
First, carefully hand-crafted by DBAs so that every partition is
different from other and so is every join between two partitions.
There will be lesser number of partitions, but creating paths for each
join between partitions will be crucial from performance point of
view. Consider, for example, systems which use partitions to
consolidate results from different sources for analytical purposes or
sharding. If we consider various points you have listed in [1]http://postgresql.nabble.com/design-for-a-partitioning-feature-was-inheritance-td5921603.html as to
why a partition is equivalent to a table, each join between partitions
is going to have very different characteristics and thus deserves a
set of paths for its own. Add to that possibility of partition pruning
or certain conditions affecting particular partitions, the need for
detailed planning evident.
The other usage of partitioning is to distribute the data and/or
quickly eliminate the data by partition pruning. In such case, all
partitions of a given table will have very similar properties. There
is a large chance that we will end up having same plans for every
partition and for joins between partitions. In such cases, I think it
suffices to create paths for just one or may be a handful partitions
of join and repeat that plan for other partitions of join. But in such
cases it also makes sense to have a light-weight representation for
partitions as compared to partitions being a full-fledged tables. If
we have such a light-weight representation, we may not even create
RelOptInfos representing joins between partitions, and different paths
for each join between partitions.
One way of attacking this problem is to gang together partitions which
are equivalent for planning purposes, as discussed in the paper "Join
Optimization Techniques for Partitioned Tables" by Herodotou, Borisov,
and Babu. However, it's not exactly clear how to do this: we could
gang together partitions that have the same index definitions, but the
sizes of the heaps, the sizes of their indexes, and the row counts
will vary from one partition to the next, and any of those things
could cause the plan choice to be different for one partition vs. the
next. We could try to come up with heuristics for when those things
are likely to be true. For example, suppose we compute the set of
partitions such that all joined relations have matching index
definitions on all tables; then, we take the biggest table in the set
and consider all tables more than half that size as part of one gang.
The biggest table becomes the leader and we compute partition-wise
paths for just that partition; the other members of the gang will
eventually get a plan that is of the same shape, but we don't actually
create it that plan until after scan/join planning is concluded.
Section 5 of that paper talks about clustering partitions together for
joining, only when there is 1:m OR n:1 partition matching for join. In
such a case, it clusters all the partitions from one relation that are
all joined with a single partition of the other relation. But I think
your idea to gang up partitions with similar properties may reduce the
number of paths we create but as you have mentioned how to gang them
up is not very clear. There are just too many factors like
availability of the indexes, sizes of tables, size of intermediate
results etc. which make it difficult to identify the properties used
for ganging up. Even after we do that, in the worst case, we will
still end up creating paths for all partitions of all joins, thus
causing increase in paths proportionate to the number of partitions.
In the section 6.3, the paper mentions that the number of paths
retained are linear in the number of child joins per parent join. So,
it's clear that the paper never considered linear increase in the
paths to be a problem or at least a problem that that work had to
solve. Now, it's surprising that their memory usage increased by 7% to
10%. But 1. they might be measuring total memory and not the memory
used by the planner and they experimented with PostgreSQL 8.3.7, which
probably tried much less number of paths than the current optimizer.
Another idea is to try to reduce peak memory usage by performing
planning separately for each partition-set. For example, suppose we
decide to do a partition-wise join of A, B, and C. Initially, this
gets represented as a PartitionJoinPath tree, like this:PartitionJoinPath
-> AppendPath for A
-> PartitionJoinPath
-> AppendPath for B
-> AppendPath for CBecause we haven't created individual join paths for the members, this
doesn't use much memory. Somehow, we come up with a cost for the
PartitionJoinPath; it probably won't be entirely accurate. Once
scan/join planning is concluded, if our final path contains a
PartitionJoinPath, we go back and loop over the partitions.
A typical join tree will be composite: some portion partitioned and
some portion unpartitioned or different portions partitioned by
different partition schemes. In such case, inaccurate costs for
PartitionJoinPath, can affect the plan heavily, causing a suboptimal
path to be picked. Assuming that partitioning will be useful for large
sets of data, choosing a suboptimal plan can be more dangerous than
consuming memory for creating paths.
If we could come up with costs for PartitionJoinPath using some
methods of interpolation, say by sampling few partitions and then
extrapolating their costs for entire PartitionJoinPath, we can use
this method. But unless the partitions have very similar
characteristics or have such characteristics that costs can be guessed
based on the differences between the characteristics, I do not see how
that can happen. For example, while costing a PartitionJoinPath with
pathkeys, the costs will change a lot based on whether underlying
relations have indexes, or which join methods are used, which in turn
is based on properties on the partitions. Same is the case for paths
with parameterization. All such paths are important when a partitioned
join relation joins with other unpartitioned relation or a partitioned
relation with different partitioning scheme.
When each partition of base relation being joined has different
properties, the cost for join between one set of partitions can differ
from join between other set of partitions. Not only that, the costs
for various properties of resultant paths like pathkeys,
parameterization can vary a lot, depending upon the available indexes
and estimates of rows for each join. So, we need to come up with these
cost estimates separately for each join between partitions to come up
with cost of each PartitionJoinPath. If we have to calculate those
costs to create PartitionJoinPath, we better save them in paths rather
than recalculating them in the second round of planning for joins
between partitions.
For each
partition, we switch to a new memory context, perform planning, copy
the best path and its substructure back to the parent context, and
then reset the context.
This could be rather tricky. It assumes that all the code that creates
paths for joins, should not allocate any memory which is linked to
some object in a context that lives longer than the path creation
context. There is some code like create_join_clause() or
make_canonical_pathkey(), which carefully chooses which memory context
to allocate memory in. But can we ensure it always? postgres_fdw for
example allocates memory for PgFdwRelationInfo in current memory
context and attaches it in RelOptInfo, which should be in the
planner's original context. So, if we create a new memory context for
each partition, fpinfos would be invalidated when those contexts are
released. Not that, we can not enforce some restriction on the memory
usage while planning, it's hard to enforce it and bugs arising from it
may go unnoticed. GEQO planner might have its own problems with this
approach. Third party FDWs will pose a problem.
A possible solution would be to keep the track of used paths using a
reference count. Once the paths for given join tree are created, free
up the unused paths by traversing pathlist in each of the RelOptInfos.
Attached patch has a prototype implementation for the same. There are
some paths which are not linked to RelOptInfos, which need a bit
different treatment, but they can be handled too.
In that way, peak memory usage only grows by
about a factor of 2 rather than a factor equal to the partition count,
because we don't need to keep every possibly-useful path for every
partition all at the same time, but rather every possibly-useful path
for a single partition.Maybe there are other ideas but I have a feeling any way you slice it
this is going to be a lot of work.
For the case of carefully hand-crafted partitions, I think, users
would expect the planner to use really the best plan and thus may be
willing to accommodate for increased memory usage. Going by any
approach that does not create the paths for joins between partitions
is not guaranteed to give the best plan. Users willing to provide
increased memory will be unhappy if we do not give them the best path.
The user who creates hundreds of partitions, will ideally be using
pretty powerful servers with a lot of memory. On such servers, the
linear increase in memory for paths may not be as bad as you are
portraying above, as long as its producing the best plan.
Just joining partitioned tables with hundreds of partitions does not
increase the number of paths. Number of paths increases when two
partitioned tables with similar partitioning scheme are joined with
equality condition on partition key. Unless we consider
repartitioning, how many of the joining relations share same
partitioning scheme? Section 8.6 mentions, "no TPC-H query plan,
regardless of the partitioning scheme, contains n-way child joins for
n >= 4. Maximum partitions that the paper mentions is 168 (Table 3).
My VM which has 8GB RAM and 4 cores handled that case pretty well. We
may add logic to free up space used by useless paths post-join to free
up some memory for next stages of query execution.
There will still be users, for whom the increase in the memory usage
is unexpected. Those will need to be educated or for them we might
take heuristic PartitionJoinPath based approach discussed above. But I
don't think that heuristic approach should be the default case. May be
we should supply a GUC which can switch between the approaches.
Some ideas for GUCs are 1. delay_partition_wise_join - when ON uses
the heuristic approach of PartitionJoinPath.
2. A GUC similar to join_collapse_limit may be used to limit the
number of partitioned relations being joined using partition-wise join
technique. A value of 1, indicates enable_partition_wise_join = false.
So, we may replace enable_partition_wise_join withe this GUC.
3. A GUC max_joinable_partitions (open to suggestions for name) may
specify the maximum number of partitions that two relations may have
to be eligible for partition-wise join.
I guess, using these GUCs allows a user handle the trade-off between
getting the best plan and memory usage consciously. I think, users
would like to accept a suboptimal plans consciously than being thrown
a suboptimal plan without choice.
[1]: http://postgresql.nabble.com/design-for-a-partitioning-feature-was-inheritance-td5921603.html
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
free_unused_paths.patchtext/x-patch; charset=US-ASCII; name=free_unused_paths.patchDownload
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index e42ef98..6a730ca 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -2200,20 +2200,75 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
#ifdef OPTIMIZER_DEBUG
debug_print_rel(root, rel);
#endif
}
}
+ /* Release all the memory consumed by unreferenced paths. */
+ for (lev = levels_needed - 1; lev >= 1; lev--)
+ {
+ ListCell *lc;
+ foreach (lc, root->join_rel_level[lev])
+ {
+ ListCell *lc_path;
+ RelOptInfo *rel = (RelOptInfo *) lfirst(lc);
+
+ elog(NOTICE, "path list length before deleting %d", list_length(rel->pathlist));
+
+ lc_path = list_head(rel->pathlist);
+ while(lc_path)
+ {
+ Path *path = (Path *) lfirst(lc_path);
+
+ lc_path = lnext(lc_path);
+
+ /* Free the path if none references it. */
+ if (path->num_refs == 1)
+ {
+ elog(NOTICE, "freed unreferenced path %p of type %d", path,
+ path->pathtype);
+
+ rel->pathlist = list_delete_ptr(rel->pathlist, path);
+ free_path(path);
+ }
+ }
+
+ elog(NOTICE, "path list length after deleting %d", list_length(rel->pathlist));
+
+ elog(NOTICE, "partial path list length before deleting %d", list_length(rel->partial_pathlist));
+ /* Do the same for partial pathlist. */
+ lc_path = list_head(rel->partial_pathlist);
+ while(lc_path)
+ {
+ Path *path = (Path *) lfirst(lc_path);
+
+ lc_path = lnext(lc_path);
+
+ /* Free the path if none references it. */
+ if (path->num_refs == 1)
+ {
+ elog(NOTICE, "freed unreferenced path %p of type %d", path,
+ path->pathtype);
+
+ rel->partial_pathlist = list_delete_ptr(rel->partial_pathlist, path);
+ free_path(path);
+ }
+ }
+
+ elog(NOTICE, "partial path list length after deleting %d", list_length(rel->partial_pathlist));
+ }
+ }
+
/*
* We should have a single rel at the final level.
*/
if (root->join_rel_level[levels_needed] == NIL)
elog(ERROR, "failed to build any %d-way joins", levels_needed);
Assert(list_length(root->join_rel_level[levels_needed]) == 1);
rel = (RelOptInfo *) linitial(root->join_rel_level[levels_needed]);
root->join_rel_level = NULL;
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index abb7507..6b34f6a 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -39,21 +39,21 @@ typedef enum
} PathCostComparison;
/*
* STD_FUZZ_FACTOR is the normal fuzz factor for compare_path_costs_fuzzily.
* XXX is it worth making this user-controllable? It provides a tradeoff
* between planner runtime and the accuracy of path cost comparisons.
*/
#define STD_FUZZ_FACTOR 1.01
static List *translate_sub_tlist(List *tlist, int relid);
-
+static void unref_path(Path *path);
/*****************************************************************************
* MISC. PATH UTILITIES
*****************************************************************************/
/*
* compare_path_costs
* Return -1, 0, or +1 according as path1 is cheaper, the same cost,
* or more expensive than path2 for the specified criterion.
*/
@@ -581,22 +581,21 @@ add_path(RelOptInfo *parent_rel, Path *new_path)
* Remove current element from pathlist if dominated by new.
*/
if (remove_old)
{
parent_rel->pathlist = list_delete_cell(parent_rel->pathlist,
p1, p1_prev);
/*
* Delete the data pointed-to by the deleted cell, if possible
*/
- if (!IsA(old_path, IndexPath))
- pfree(old_path);
+ free_path(old_path);
/* p1_prev does not advance */
}
else
{
/* new belongs after this old path if it has cost >= old's */
if (new_path->total_cost >= old_path->total_cost)
insert_after = p1;
/* p1_prev advances */
p1_prev = p1;
}
@@ -610,26 +609,26 @@ add_path(RelOptInfo *parent_rel, Path *new_path)
break;
}
if (accept_new)
{
/* Accept the new path: insert it at proper place in pathlist */
if (insert_after)
lappend_cell(parent_rel->pathlist, insert_after, new_path);
else
parent_rel->pathlist = lcons(new_path, parent_rel->pathlist);
+ new_path->num_refs++;
}
else
{
/* Reject and recycle the new path */
- if (!IsA(new_path, IndexPath))
- pfree(new_path);
+ free_path(new_path);
}
}
/*
* add_path_precheck
* Check whether a proposed new path could possibly get accepted.
* We assume we know the path's pathkeys and parameterization accurately,
* and have lower bounds for its costs.
*
* Note that we do not know the path's rowcount, since getting an estimate for
@@ -821,21 +820,21 @@ add_partial_path(RelOptInfo *parent_rel, Path *new_path)
/*
* Remove current element from partial_pathlist if dominated by new.
*/
if (remove_old)
{
parent_rel->partial_pathlist =
list_delete_cell(parent_rel->partial_pathlist, p1, p1_prev);
/* we should not see IndexPaths here, so always safe to delete */
Assert(!IsA(old_path, IndexPath));
- pfree(old_path);
+ free_path(old_path);
/* p1_prev does not advance */
}
else
{
/* new belongs after this old path if it has cost >= old's */
if (new_path->total_cost >= old_path->total_cost)
insert_after = p1;
/* p1_prev advances */
p1_prev = p1;
}
@@ -850,27 +849,28 @@ add_partial_path(RelOptInfo *parent_rel, Path *new_path)
}
if (accept_new)
{
/* Accept the new path: insert it at proper place */
if (insert_after)
lappend_cell(parent_rel->partial_pathlist, insert_after, new_path);
else
parent_rel->partial_pathlist =
lcons(new_path, parent_rel->partial_pathlist);
+ new_path->num_refs++;
}
else
{
/* we should not see IndexPaths here, so always safe to delete */
Assert(!IsA(new_path, IndexPath));
/* Reject and recycle the new path */
- pfree(new_path);
+ free_path(new_path);
}
}
/*
* add_partial_path_precheck
* Check whether a proposed new partial path could possibly get accepted.
*
* Unlike add_path_precheck, we can ignore startup cost and parameterization,
* since they don't matter for partial paths (see add_partial_path). But
* we do want to make sure we don't add a partial path if there's already
@@ -1079,20 +1079,21 @@ create_bitmap_heap_path(PlannerInfo *root,
pathnode->path.parent = rel;
pathnode->path.pathtarget = rel->reltarget;
pathnode->path.param_info = get_baserel_parampathinfo(root, rel,
required_outer);
pathnode->path.parallel_aware = false;
pathnode->path.parallel_safe = rel->consider_parallel;
pathnode->path.parallel_workers = 0;
pathnode->path.pathkeys = NIL; /* always unordered */
pathnode->bitmapqual = bitmapqual;
+ bitmapqual->num_refs++;
cost_bitmap_heap_scan(&pathnode->path, root, rel,
pathnode->path.param_info,
bitmapqual, loop_count);
return pathnode;
}
/*
* create_bitmap_and_path
@@ -1228,20 +1229,22 @@ create_append_path(RelOptInfo *rel, List *subpaths, Relids required_outer,
* but since it doesn't do any selection or projection, it is a pretty
* cheap node.
*/
pathnode->path.rows = 0;
pathnode->path.startup_cost = 0;
pathnode->path.total_cost = 0;
foreach(l, subpaths)
{
Path *subpath = (Path *) lfirst(l);
+ subpath->num_refs++;
+
pathnode->path.rows += subpath->rows;
if (l == list_head(subpaths)) /* first node? */
pathnode->path.startup_cost = subpath->startup_cost;
pathnode->path.total_cost += subpath->total_cost;
pathnode->path.parallel_safe = pathnode->path.parallel_safe &&
subpath->parallel_safe;
/* All child paths must have same parameterization */
Assert(bms_equal(PATH_REQ_OUTER(subpath), required_outer));
@@ -1290,20 +1293,21 @@ create_merge_append_path(PlannerInfo *root,
/*
* Add up the sizes and costs of the input paths.
*/
pathnode->path.rows = 0;
input_startup_cost = 0;
input_total_cost = 0;
foreach(l, subpaths)
{
Path *subpath = (Path *) lfirst(l);
+ subpath->num_refs++;
pathnode->path.rows += subpath->rows;
pathnode->path.parallel_safe = pathnode->path.parallel_safe &&
subpath->parallel_safe;
if (pathkeys_contained_in(pathkeys, subpath->pathkeys))
{
/* Subpath is adequately ordered, we won't need to sort it */
input_startup_cost += subpath->startup_cost;
input_total_cost += subpath->total_cost;
}
@@ -1678,20 +1682,21 @@ create_gather_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
pathnode->path.parent = rel;
pathnode->path.pathtarget = target;
pathnode->path.param_info = get_baserel_parampathinfo(root, rel,
required_outer);
pathnode->path.parallel_aware = false;
pathnode->path.parallel_safe = false;
pathnode->path.parallel_workers = subpath->parallel_workers;
pathnode->path.pathkeys = NIL; /* Gather has unordered result */
pathnode->subpath = subpath;
+ subpath->num_refs++;
pathnode->single_copy = false;
if (pathnode->path.parallel_workers == 0)
{
pathnode->path.parallel_workers = 1;
pathnode->path.pathkeys = subpath->pathkeys;
pathnode->single_copy = true;
}
cost_gather(pathnode, root, rel, pathnode->path.param_info, rows);
@@ -1999,21 +2004,23 @@ create_nestloop_path(PlannerInfo *root,
required_outer,
&restrict_clauses);
pathnode->path.parallel_aware = false;
pathnode->path.parallel_safe = joinrel->consider_parallel &&
outer_path->parallel_safe && inner_path->parallel_safe;
/* This is a foolish way to estimate parallel_workers, but for now... */
pathnode->path.parallel_workers = outer_path->parallel_workers;
pathnode->path.pathkeys = pathkeys;
pathnode->jointype = jointype;
pathnode->outerjoinpath = outer_path;
+ outer_path->num_refs++;
pathnode->innerjoinpath = inner_path;
+ inner_path->num_refs++;
pathnode->joinrestrictinfo = restrict_clauses;
final_cost_nestloop(root, pathnode, workspace, sjinfo, semifactors);
return pathnode;
}
/*
* create_mergejoin_path
* Creates a pathnode corresponding to a mergejoin join between
@@ -2062,21 +2069,23 @@ create_mergejoin_path(PlannerInfo *root,
required_outer,
&restrict_clauses);
pathnode->jpath.path.parallel_aware = false;
pathnode->jpath.path.parallel_safe = joinrel->consider_parallel &&
outer_path->parallel_safe && inner_path->parallel_safe;
/* This is a foolish way to estimate parallel_workers, but for now... */
pathnode->jpath.path.parallel_workers = outer_path->parallel_workers;
pathnode->jpath.path.pathkeys = pathkeys;
pathnode->jpath.jointype = jointype;
pathnode->jpath.outerjoinpath = outer_path;
+ outer_path->num_refs++;
pathnode->jpath.innerjoinpath = inner_path;
+ inner_path->num_refs++;
pathnode->jpath.joinrestrictinfo = restrict_clauses;
pathnode->path_mergeclauses = mergeclauses;
pathnode->outersortkeys = outersortkeys;
pathnode->innersortkeys = innersortkeys;
/* pathnode->materialize_inner will be set by final_cost_mergejoin */
final_cost_mergejoin(root, pathnode, workspace, sjinfo);
return pathnode;
}
@@ -2136,21 +2145,23 @@ create_hashjoin_path(PlannerInfo *root,
* and then we could assume that the output inherits the outer relation's
* ordering, which might save a sort step. However there is considerable
* downside if our estimate of the inner relation size is badly off. For
* the moment we don't risk it. (Note also that if we wanted to take this
* seriously, joinpath.c would have to consider many more paths for the
* outer rel than it does now.)
*/
pathnode->jpath.path.pathkeys = NIL;
pathnode->jpath.jointype = jointype;
pathnode->jpath.outerjoinpath = outer_path;
+ outer_path->num_refs++;
pathnode->jpath.innerjoinpath = inner_path;
+ inner_path->num_refs++;
pathnode->jpath.joinrestrictinfo = restrict_clauses;
pathnode->path_hashclauses = hashclauses;
/* final_cost_hashjoin will fill in pathnode->num_batches */
final_cost_hashjoin(root, pathnode, workspace, sjinfo, semifactors);
return pathnode;
}
/*
@@ -3202,10 +3213,87 @@ reparameterize_path(PlannerInfo *root, Path *path,
rel,
spath->subpath,
spath->path.pathkeys,
required_outer);
}
default:
break;
}
return NULL;
}
+
+void
+free_path(Path *path)
+{
+ /* Decrement the reference counts of paths referenced by this one. */
+ switch(path->pathtype)
+ {
+ case T_SeqScan:
+ case T_IndexScan:
+ case T_IndexOnlyScan:
+ /* Simple paths do nothing. */
+ break;
+
+ case T_MergeJoin:
+ case T_HashJoin:
+ case T_NestLoop:
+ {
+ JoinPath *jpath = (JoinPath *)path;
+ unref_path(jpath->outerjoinpath);
+ unref_path(jpath->innerjoinpath);
+ }
+ break;
+
+ case T_Append:
+ case T_MergeAppend:
+ {
+ AppendPath *appath = (AppendPath *)path;
+ ListCell *lc;
+
+ foreach (lc, appath->subpaths)
+ {
+ Path *path = lfirst(lc);
+ unref_path(path);
+ }
+ }
+ break;
+
+ case T_Gather:
+ {
+ GatherPath *gpath = (GatherPath *) path;
+ unref_path(gpath->subpath);
+ }
+ break;
+
+ case T_BitmapHeapScan:
+ {
+ BitmapHeapPath *bhpath = (BitmapHeapPath *)path;
+ unref_path(bhpath->bitmapqual);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized path type %d", path->pathtype);
+ break;
+ }
+
+ /* Now reclaim the memory. */
+ if (!IsA(path, IndexPath))
+ pfree(path);
+}
+
+static void
+unref_path(Path *path)
+{
+ if (!path)
+ return;
+
+ path->num_refs--;
+
+ if (path->num_refs == 0)
+ {
+ elog(NOTICE, "freed an unreferenced path %p of type %d not added to rel pathlist",
+ path, path->pathtype);
+
+ free_path(path);
+ }
+}
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 3a1255a..a58d71b 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -891,20 +891,21 @@ typedef struct Path
int parallel_workers; /* desired # of workers; 0 = not
* parallel */
/* estimated size/costs for path (see costsize.c for more info) */
double rows; /* estimated number of result tuples */
Cost startup_cost; /* cost expended before fetching any tuples */
Cost total_cost; /* total cost (assuming all tuples fetched) */
List *pathkeys; /* sort ordering of path's output */
/* pathkeys is a List of PathKey nodes; see above */
+ int num_refs; /* Number of objects referencing this path. */
} Path;
/* Macro for extracting a path's parameterization relids; beware double eval */
#define PATH_REQ_OUTER(path) \
((path)->param_info ? (path)->param_info->ppi_req_outer : (Relids) NULL)
/*----------
* IndexPath represents an index scan over a single index.
*
* This struct is used for both regular indexscans and index-only scans;
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..d658cd3 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -211,12 +211,13 @@ extern List *select_outer_pathkeys_for_merge(PlannerInfo *root,
extern List *make_inner_pathkeys_for_merge(PlannerInfo *root,
List *mergeclauses,
List *outer_pathkeys);
extern List *truncate_useless_pathkeys(PlannerInfo *root,
RelOptInfo *rel,
List *pathkeys);
extern bool has_useful_pathkeys(PlannerInfo *root, RelOptInfo *rel);
extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+extern void free_path(Path *path);
#endif /* PATHS_H */
On Fri, Oct 28, 2016 at 3:09 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
I think there are going to be two kinds of partitioning use-cases.
First, carefully hand-crafted by DBAs so that every partition is
different from other and so is every join between two partitions.
There will be lesser number of partitions, but creating paths for each
join between partitions will be crucial from performance point of
view. Consider, for example, systems which use partitions to
consolidate results from different sources for analytical purposes or
sharding. If we consider various points you have listed in [1] as to
why a partition is equivalent to a table, each join between partitions
is going to have very different characteristics and thus deserves a
set of paths for its own. Add to that possibility of partition pruning
or certain conditions affecting particular partitions, the need for
detailed planning evident.The other usage of partitioning is to distribute the data and/or
quickly eliminate the data by partition pruning. In such case, all
partitions of a given table will have very similar properties. There
is a large chance that we will end up having same plans for every
partition and for joins between partitions. In such cases, I think it
suffices to create paths for just one or may be a handful partitions
of join and repeat that plan for other partitions of join. But in such
cases it also makes sense to have a light-weight representation for
partitions as compared to partitions being a full-fledged tables. If
we have such a light-weight representation, we may not even create
RelOptInfos representing joins between partitions, and different paths
for each join between partitions.
I'm not sure I see a real distinction between these two use cases. I
think that the problem of differing data distribution between
partitions is almost always going to be an issue. Take the simple
case of an "orders" table which is partitioned by month. First, the
month that's currently in progress may be much smaller than a typical
completed month. Second, many businesses are seasonal and may have
many more orders at certain times of year. For example, in American
retail, many businesses have large spikes in December. I think some
businesses may do four times as much business in December as any other
month, for example. So you will have that sort of variation, at
least.
A typical join tree will be composite: some portion partitioned and
some portion unpartitioned or different portions partitioned by
different partition schemes. In such case, inaccurate costs for
PartitionJoinPath, can affect the plan heavily, causing a suboptimal
path to be picked. Assuming that partitioning will be useful for large
sets of data, choosing a suboptimal plan can be more dangerous than
consuming memory for creating paths.
Well, sure. But, I mean, every simplifying assumption which the
planner makes to limit resource consumption could have that effect.
join_collapse_limit, for example, can cause horrible plans. However,
we have it anyway, because the alternative of having planning take far
too long is unpalatable. Planning is always, at some level,
guesswork.
For each
partition, we switch to a new memory context, perform planning, copy
the best path and its substructure back to the parent context, and
then reset the context.This could be rather tricky. It assumes that all the code that creates
paths for joins, should not allocate any memory which is linked to
some object in a context that lives longer than the path creation
context. There is some code like create_join_clause() or
make_canonical_pathkey(), which carefully chooses which memory context
to allocate memory in. But can we ensure it always? postgres_fdw for
example allocates memory for PgFdwRelationInfo in current memory
context and attaches it in RelOptInfo, which should be in the
planner's original context. So, if we create a new memory context for
each partition, fpinfos would be invalidated when those contexts are
released. Not that, we can not enforce some restriction on the memory
usage while planning, it's hard to enforce it and bugs arising from it
may go unnoticed. GEQO planner might have its own problems with this
approach. Third party FDWs will pose a problem.
Yep, there are problems. :-)
A possible solution would be to keep the track of used paths using a
reference count. Once the paths for given join tree are created, free
up the unused paths by traversing pathlist in each of the RelOptInfos.
Attached patch has a prototype implementation for the same. There are
some paths which are not linked to RelOptInfos, which need a bit
different treatment, but they can be handled too.
So, if you apply this with your previous patch, how much does it cut
down memory consumption?
In that way, peak memory usage only grows by
about a factor of 2 rather than a factor equal to the partition count,
because we don't need to keep every possibly-useful path for every
partition all at the same time, but rather every possibly-useful path
for a single partition.Maybe there are other ideas but I have a feeling any way you slice it
this is going to be a lot of work.For the case of carefully hand-crafted partitions, I think, users
would expect the planner to use really the best plan and thus may be
willing to accommodate for increased memory usage. Going by any
approach that does not create the paths for joins between partitions
is not guaranteed to give the best plan. Users willing to provide
increased memory will be unhappy if we do not give them the best path.The user who creates hundreds of partitions, will ideally be using
pretty powerful servers with a lot of memory. On such servers, the
linear increase in memory for paths may not be as bad as you are
portraying above, as long as its producing the best plan.
No, I don't agree. We should be trying to build something that scales
well. I've heard reports of customers with hundreds or even thousands
of partitions; I think it is quite reasonable to think that we need to
scale to 1000 partitions. If we use 3MB of memory to plan a query
involving unpartitioned, using 3GB to plan a query where the main
tables have been partitioned 1000 ways does not seem reasonable to me.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Mon, Oct 31, 2016 at 6:37 PM, Robert Haas <robertmhaas@gmail.com> wrote:
On Fri, Oct 28, 2016 at 3:09 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:I think there are going to be two kinds of partitioning use-cases.
First, carefully hand-crafted by DBAs so that every partition is
different from other and so is every join between two partitions.
There will be lesser number of partitions, but creating paths for each
join between partitions will be crucial from performance point of
view. Consider, for example, systems which use partitions to
consolidate results from different sources for analytical purposes or
sharding. If we consider various points you have listed in [1] as to
why a partition is equivalent to a table, each join between partitions
is going to have very different characteristics and thus deserves a
set of paths for its own. Add to that possibility of partition pruning
or certain conditions affecting particular partitions, the need for
detailed planning evident.The other usage of partitioning is to distribute the data and/or
quickly eliminate the data by partition pruning. In such case, all
partitions of a given table will have very similar properties. There
is a large chance that we will end up having same plans for every
partition and for joins between partitions. In such cases, I think it
suffices to create paths for just one or may be a handful partitions
of join and repeat that plan for other partitions of join. But in such
cases it also makes sense to have a light-weight representation for
partitions as compared to partitions being a full-fledged tables. If
we have such a light-weight representation, we may not even create
RelOptInfos representing joins between partitions, and different paths
for each join between partitions.I'm not sure I see a real distinction between these two use cases. I
think that the problem of differing data distribution between
partitions is almost always going to be an issue. Take the simple
case of an "orders" table which is partitioned by month. First, the
month that's currently in progress may be much smaller than a typical
completed month. Second, many businesses are seasonal and may have
many more orders at certain times of year. For example, in American
retail, many businesses have large spikes in December. I think some
businesses may do four times as much business in December as any other
month, for example. So you will have that sort of variation, at
least.A typical join tree will be composite: some portion partitioned and
some portion unpartitioned or different portions partitioned by
different partition schemes. In such case, inaccurate costs for
PartitionJoinPath, can affect the plan heavily, causing a suboptimal
path to be picked. Assuming that partitioning will be useful for large
sets of data, choosing a suboptimal plan can be more dangerous than
consuming memory for creating paths.Well, sure. But, I mean, every simplifying assumption which the
planner makes to limit resource consumption could have that effect.
join_collapse_limit, for example, can cause horrible plans. However,
we have it anyway, because the alternative of having planning take far
too long is unpalatable. Planning is always, at some level,
guesswork.
My point is, this behaviour is configurable. Users who are ready to
spend time and resources to get the best plan are still able to do so,
by choosing a higher limit on join_collapse_limit. Those who can not
afford to do so, are ready to use inferior plans willingly by setting
join_collapse_limit to a lower number.
A possible solution would be to keep the track of used paths using a
reference count. Once the paths for given join tree are created, free
up the unused paths by traversing pathlist in each of the RelOptInfos.
Attached patch has a prototype implementation for the same. There are
some paths which are not linked to RelOptInfos, which need a bit
different treatment, but they can be handled too.So, if you apply this with your previous patch, how much does it cut
down memory consumption?
Answered this below:
In that way, peak memory usage only grows by
about a factor of 2 rather than a factor equal to the partition count,
because we don't need to keep every possibly-useful path for every
partition all at the same time, but rather every possibly-useful path
for a single partition.Maybe there are other ideas but I have a feeling any way you slice it
this is going to be a lot of work.For the case of carefully hand-crafted partitions, I think, users
would expect the planner to use really the best plan and thus may be
willing to accommodate for increased memory usage. Going by any
approach that does not create the paths for joins between partitions
is not guaranteed to give the best plan. Users willing to provide
increased memory will be unhappy if we do not give them the best path.The user who creates hundreds of partitions, will ideally be using
pretty powerful servers with a lot of memory. On such servers, the
linear increase in memory for paths may not be as bad as you are
portraying above, as long as its producing the best plan.No, I don't agree. We should be trying to build something that scales
well. I've heard reports of customers with hundreds or even thousands
of partitions; I think it is quite reasonable to think that we need to
scale to 1000 partitions. If we use 3MB of memory to plan a query
involving unpartitioned, using 3GB to plan a query where the main
tables have been partitioned 1000 ways does not seem reasonable to me.
Here are memory consumption numbers.
For a simple query "select * from v5_prt100", where v5_prt100 is a
view on a 5 way self join of table prt100, which is a plain table with
100 partitions without any indexes.
postgres=# \d+ v5_prt100
View "part_mem_usage.v5_prt100"
Column | Type | Modifiers | Storage | Description
--------+--------+-----------+----------+-------------
t1 | prt100 | | extended |
t2 | prt100 | | extended |
t3 | prt100 | | extended |
t4 | prt100 | | extended |
t5 | prt100 | | extended |
View definition:
SELECT t1.*::prt100 AS t1,
t2.*::prt100 AS t2,
t3.*::prt100 AS t3,
t4.*::prt100 AS t4,
t5.*::prt100 AS t5
FROM prt100 t1,
prt100 t2,
prt100 t3,
prt100 t4,
prt100 t5
WHERE t1.a = t2.a AND t2.a = t3.a AND t3.a = t4.a AND t4.a = t5.a;
postgres=# \d prt100
Table "part_mem_usage.prt100"
Column | Type | Modifiers
--------+-------------------+-----------
a | integer |
b | integer |
c | character varying |
Partition Key: RANGE (a)
Number of partitions: 100 (Use \d+ to list them.)
Without partition-wise join the standard_planner() consumes 4311 kB
memory of which 150 kB is consumed in add_paths_to_joinrel().
With partition-wise join standard_planner() consumes 65MB memory,
which is 16 times more (not 100 times more as you suspected above). Of
this bloat 16MB is consumed for creating child join paths whereas
651kB is consumed in creating append paths. That's 100 times bloat for
path creation. Rest of the memory bloat is broken down as 9MB to
create child join RelOptInfos, 29MB to translate restrict clauses, 8MB
to translate target lists. 2MB for creating special join info for
children, 2MB goes into creating plans.
If we apply logic to free unused paths, the memory consumption reduces
as follows
Without partition-wise join standard_planner() consumes 4268 kB
(against 4311kB earlier) of which 123kB (against 150kB earlier) is
consumed in add_paths_to_joinrel().
With partition-wise join, standard_planner() consumes 63MB (against
65MB earlier). Child join paths still consume 13 MB (against 16MB
earlier), which is still 100 times that without using partition-wise
join. We may shave off some memory consumption by using better methods
than translating expressions, but we will continue to have bloats
introduced by paths, RelOptInfos for child joins etc.
So, I am thinking about your approach of creating PartitionJoinPaths
without actually creating child paths and then at a later stage
actually plan the child joins. Here's rough sketch of how that may be
done.
At the time of creating regular paths, we identify the join orders
which can use partition-wise join and save those in the RelOptInfo of
the parent table. If no such join order exists, we do not create
PartitionJoinPaths for that relation. Otherwise, once we have
considered all the join orders i.e. in
generate_partition_wise_join_paths(), we create one PartitionJoinPath
for every path that has survived in the parent or at least for every
path that has distinct properties like pathkeys or parameterisation,
with those properties.
At the time of creating plans, if PartitionJoinPath is chosen, we
actually create paths for every partition of that relation
recursively. The path creation logic is carried out in a different
memory context. Amongst the paths that survive, we choose the best
path that has the same properties as PartitionJoinPath. We would
expect all parameterized paths to be retained and any unparameterized
path can be sorted to match the pathkeys of reference
PartitionJoinPath. We then create the plan out of this path and copy
it into the outer memory context and release the memory context used
for path creation. This is similar to how prepared statements save
their plans. Once we have the plan, the memory consumed by paths won't
be referenced, and hence can not create problems. At the end we create
an Append/MergeAppend plan with all the child plans and return it.
Costing PartitionJoinPath needs more thought so that we don't end up
with bad overall plans. Here's an idea. Partition-wise joins are
better compared to the unpartitioned ones, because of the smaller
sizes of partitions. If we think of join as O(MN) operation where M
and N are sizes of unpartitioned tables being joined, partition-wise
join computes P joins each with average O(M/P * N/P) order where P is
the number of partitions, which is still O(MN) with constant factor
reduced by P times. I think, we need to apply similar logic to
costing. Let's say cost of a join is J(M, N) = S (M, N) + R (M, N)
where S and R are setup cost and joining cost (for M, N rows) resp.
Cost of partition-wise join would be P * J(M/P, N/P) = P * S(M/P, N/P)
+ P * R(M/P, N/P). Each of the join methods will have different S and
R functions and may not be linear on the number of rows. So,
PartitionJoinPath costs are obtained from corresponding regular path
costs subjected to above transformation. This way, we will be
protected from choosing a PartitionJoinPath when it's not optimal.
Take example of a join where the joining relations are very small in
size, thus hash join on full relation is optimal compared to hash join
of each partition because of setup cost. In such a case, the function
which calculates the cost of hash table setup, would result in almost
same cost for full table as well as each of the partitions, thus
increasing P * S(M/P, N/P) as compared to S(M, N).
Let me know your comments.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
So, I am thinking about your approach of creating PartitionJoinPaths
without actually creating child paths and then at a later stage
actually plan the child joins. Here's rough sketch of how that may be
done.At the time of creating regular paths, we identify the join orders
which can use partition-wise join and save those in the RelOptInfo of
the parent table. If no such join order exists, we do not create
PartitionJoinPaths for that relation. Otherwise, once we have
considered all the join orders i.e. in
generate_partition_wise_join_paths(), we create one PartitionJoinPath
for every path that has survived in the parent or at least for every
path that has distinct properties like pathkeys or parameterisation,
with those properties.At the time of creating plans, if PartitionJoinPath is chosen, we
actually create paths for every partition of that relation
recursively. The path creation logic is carried out in a different
memory context. Amongst the paths that survive, we choose the best
path that has the same properties as PartitionJoinPath. We would
expect all parameterized paths to be retained and any unparameterized
path can be sorted to match the pathkeys of reference
PartitionJoinPath. We then create the plan out of this path and copy
it into the outer memory context and release the memory context used
for path creation. This is similar to how prepared statements save
their plans. Once we have the plan, the memory consumed by paths won't
be referenced, and hence can not create problems. At the end we create
an Append/MergeAppend plan with all the child plans and return it.Costing PartitionJoinPath needs more thought so that we don't end up
with bad overall plans. Here's an idea. Partition-wise joins are
better compared to the unpartitioned ones, because of the smaller
sizes of partitions. If we think of join as O(MN) operation where M
and N are sizes of unpartitioned tables being joined, partition-wise
join computes P joins each with average O(M/P * N/P) order where P is
the number of partitions, which is still O(MN) with constant factor
reduced by P times. I think, we need to apply similar logic to
costing. Let's say cost of a join is J(M, N) = S (M, N) + R (M, N)
where S and R are setup cost and joining cost (for M, N rows) resp.
Cost of partition-wise join would be P * J(M/P, N/P) = P * S(M/P, N/P)
+ P * R(M/P, N/P). Each of the join methods will have different S and
R functions and may not be linear on the number of rows. So,
PartitionJoinPath costs are obtained from corresponding regular path
costs subjected to above transformation. This way, we will be
protected from choosing a PartitionJoinPath when it's not optimal.
Take example of a join where the joining relations are very small in
size, thus hash join on full relation is optimal compared to hash join
of each partition because of setup cost. In such a case, the function
which calculates the cost of hash table setup, would result in almost
same cost for full table as well as each of the partitions, thus
increasing P * S(M/P, N/P) as compared to S(M, N).Let me know your comments.
I tried to measure the impact of having a memory context reset 1000
times (once for each partition) with the attached patch. Without this
patch make check in regress/ takes about 24 seconds on my laptop and
with this patch it takes 26 seconds. This is almost 10% increase in
time. I hope that's fine.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
memory_context_change.patchtext/x-patch; charset=US-ASCII; name=memory_context_change.patchDownload
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index d8c5dd3..abc34aa 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -54,6 +54,7 @@
#include "utils/rel.h"
#include "utils/selfuncs.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
#include "utils/syscache.h"
@@ -192,6 +193,9 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
Plan *top_plan;
ListCell *lp,
*lr;
+ MemoryContext temp_context;
+ int i;
+ MemoryContext default_context;
/* Cursor options may come from caller or from DECLARE CURSOR stmt */
if (parse->utilityStmt &&
@@ -432,6 +436,24 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
result->invalItems = glob->invalItems;
result->nParamExec = glob->nParamExec;
+ temp_context = AllocSetContextCreate(CurrentMemoryContext,
+ "TemporaryContext",
+ ALLOCSET_DEFAULT_SIZES);
+
+ /* Test the time impact of creating and destroying 1000 memory contexts. */
+ for (i = 0; i < 1000; i++)
+ {
+ RelOptInfo *rel;
+ default_context = MemoryContextSwitchTo(temp_context);
+ rel = makeNode(RelOptInfo);
+ pfree(rel);
+ MemoryContextSwitchTo(default_context);
+ MemoryContextResetAndDeleteChildren(temp_context);
+ }
+
+ MemoryContextSwitchTo(default_context);
+ MemoryContextDelete(temp_context);
+
return result;
}
On Fri, Nov 4, 2016 at 6:52 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
Costing PartitionJoinPath needs more thought so that we don't end up
with bad overall plans. Here's an idea. Partition-wise joins are
better compared to the unpartitioned ones, because of the smaller
sizes of partitions. If we think of join as O(MN) operation where M
and N are sizes of unpartitioned tables being joined, partition-wise
join computes P joins each with average O(M/P * N/P) order where P is
the number of partitions, which is still O(MN) with constant factor
reduced by P times. I think, we need to apply similar logic to
costing. Let's say cost of a join is J(M, N) = S (M, N) + R (M, N)
where S and R are setup cost and joining cost (for M, N rows) resp.
Cost of partition-wise join would be P * J(M/P, N/P) = P * S(M/P, N/P)
+ P * R(M/P, N/P). Each of the join methods will have different S and
R functions and may not be linear on the number of rows. So,
PartitionJoinPath costs are obtained from corresponding regular path
costs subjected to above transformation. This way, we will be
protected from choosing a PartitionJoinPath when it's not optimal.
I'm not sure that I really understand the stuff with big-O notation
and M, N, and P. But I think what you are saying is that we could
cost a PartitionJoinPath by costing some of the partitions (it might
be a good idea to choose the biggest ones) and assuming the cost for
the remaining ones will be roughly proportional. That does seem like
a reasonable strategy to me.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Robert Haas <robertmhaas@gmail.com> writes:
On Fri, Nov 4, 2016 at 6:52 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Costing PartitionJoinPath needs more thought so that we don't end up
with bad overall plans. Here's an idea. Partition-wise joins are
better compared to the unpartitioned ones, because of the smaller
sizes of partitions. If we think of join as O(MN) operation where M
and N are sizes of unpartitioned tables being joined, partition-wise
join computes P joins each with average O(M/P * N/P) order where P is
the number of partitions, which is still O(MN) with constant factor
reduced by P times. I think, we need to apply similar logic to
costing. Let's say cost of a join is J(M, N) = S (M, N) + R (M, N)
where S and R are setup cost and joining cost (for M, N rows) resp.
Cost of partition-wise join would be P * J(M/P, N/P) = P * S(M/P, N/P)
+ P * R(M/P, N/P). Each of the join methods will have different S and
R functions and may not be linear on the number of rows. So,
PartitionJoinPath costs are obtained from corresponding regular path
costs subjected to above transformation. This way, we will be
protected from choosing a PartitionJoinPath when it's not optimal.
I'm not sure that I really understand the stuff with big-O notation
and M, N, and P. But I think what you are saying is that we could
cost a PartitionJoinPath by costing some of the partitions (it might
be a good idea to choose the biggest ones) and assuming the cost for
the remaining ones will be roughly proportional. That does seem like
a reasonable strategy to me.
I'm not sure to what extent the above argument depends on the assumption
that join is O(MN), but I will point out that in no case of practical
interest for large tables is it actually O(MN). That would be true
only for the stupidest possible nested-loop join method. It would be
wise to convince ourselves that the argument holds for more realistic
big-O costs, eg hash join is more like O(M+N) if all goes well.
regards, tom lane
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Mon, Nov 14, 2016 at 9:57 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Robert Haas <robertmhaas@gmail.com> writes:
On Fri, Nov 4, 2016 at 6:52 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Costing PartitionJoinPath needs more thought so that we don't end up
with bad overall plans. Here's an idea. Partition-wise joins are
better compared to the unpartitioned ones, because of the smaller
sizes of partitions. If we think of join as O(MN) operation where M
and N are sizes of unpartitioned tables being joined, partition-wise
join computes P joins each with average O(M/P * N/P) order where P is
the number of partitions, which is still O(MN) with constant factor
reduced by P times. I think, we need to apply similar logic to
costing. Let's say cost of a join is J(M, N) = S (M, N) + R (M, N)
where S and R are setup cost and joining cost (for M, N rows) resp.
Cost of partition-wise join would be P * J(M/P, N/P) = P * S(M/P, N/P)
+ P * R(M/P, N/P). Each of the join methods will have different S and
R functions and may not be linear on the number of rows. So,
PartitionJoinPath costs are obtained from corresponding regular path
costs subjected to above transformation. This way, we will be
protected from choosing a PartitionJoinPath when it's not optimal.I'm not sure that I really understand the stuff with big-O notation
and M, N, and P. But I think what you are saying is that we could
cost a PartitionJoinPath by costing some of the partitions (it might
be a good idea to choose the biggest ones) and assuming the cost for
the remaining ones will be roughly proportional. That does seem like
a reasonable strategy to me.I'm not sure to what extent the above argument depends on the assumption
that join is O(MN), but I will point out that in no case of practical
interest for large tables is it actually O(MN). That would be true
only for the stupidest possible nested-loop join method. It would be
wise to convince ourselves that the argument holds for more realistic
big-O costs, eg hash join is more like O(M+N) if all goes well.
Yeah, I agree. To recap briefly, the problem we're trying to solve
here is how to build a path for a partitionwise join without an
explosion in the amount of memory the planner uses or the number of
paths created. In the initial design, if there are N partitions per
relation, the total number of paths generated by the planner increases
by a factor of N+1, which gets ugly if, say, N = 1000, or even N =
100. To reign that in, we want to do a rough cut at costing the
partitionwise join that will be good enough to let us throw away
obviously inferior paths, and then work out the exact paths we're
going to use only for partitionwise joins that are actually selected.
I think costing one or a few of the larger sub-joins and assuming
those costs are representative is probably a reasonable approach to
that problem.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Hi Robert,
Sorry for delayed response.
The attached patch implements following ideas:
1. At the time of creating paths - If the joining relations are both
partitioned and join can use partition-wise join, we create paths for
few child-joins. Similar to inheritance relations
(set_append_rel_pathlist()), we collect paths with similar properties
from all sampled child-joins and create one PartitionJoinPath with
each set of paths. The cost of the PartitionJoinPath is obtained by
multiplying the sum of costs of paths in the given set by the ratio of
(number of rows estimated in the parent-join/sum of rows in
child-joins).
2. If the PartitionJoinPath emerges as the best path, we create paths
for each of the remaining child-joins. Then we collect paths with
properties same as the given PartitionJoinPath, one from each
child-join. These paths are converted into plans and a Merge/Append
plan is created combing these plans. The paths and plans for
child-join are created in a temporary memory context. The final plan
for each child-join is copied into planner's context and the temporary
memory context is reset.
Right now, we choose 1% or 1 (whichever is higher) child-joins to base
PartitionJoinPath costs on.
Memory consumption
-----------------------------
I tested a 5-way self-join for a table with 1000 partitions, each
partition having 1M rows. The memory consumed in standard_planner()
was measured with some granular tracking
(mem_usage_func_wise_measurement_slabwise.patch). Partition-wise join
consumed total of 289MB memory which is approx 6.6 times more than
non-partition-wise join which consumed 44MB. That's much better than
the earlier 16 times consumption for 5-way join with 100 partitions.
The extra 245MB memory was consumed by child-join RelOptInfos (48MB),
SpecialJoinInfos for child-joins (64MB), restrictlist translation
(92MB), paths for sampled child-joins (1.5MB), building targetlists
for child-joins (7MB).
In order to choose representative child-joins based on the sizes of
child-joins, we need to create all the child-join RelOptInfos. In
order to estimate sizes of child-joins, we need to create
SpecialJoinInfos and restrictlists for at least one join order for all
child-joins. For every representative child-join, we need to create
SpecialJoinInfo and restrictlist for all join orders for that
child-join. We might be able to save of restrictlist translation, if
we create restrict lists from joininfo similar to parent joins. I
haven't tried that yet.
Choosing representative child-joins:
--------------------------------------------------
There's another angle to choosing representative child joins. In a
partitioned N-way join, different joins covering different subsets of
N relations, will have different size distributions across the
partitions. This means that the child-joins costed for (N-k) joins,
may be different for those required for (N-k+1) joins. With a factor
of 1% sampling, N is such that a child-join participates in 100 joins,
we will end up creating paths for all partitions before creating
PartitionJoinPaths for the final N-way join. Hopefully that will be a
rare case and usually we will end up using paths already created. We
can not avoid creating PartitionJoinPaths for subset joins, as there
might be cases when partition-wise join will be optimal for an N-k way
join but not for N-way join. We may avoid this if we choose
representative child-joins based on their positions, in which case, we
may end up with some or all of those being empty and thus skewing the
costs heavily.
Partial paths
-----------------
AFAIU, we create partial paths for append relation, when all the
children have partial paths. Unlike parameterized paths or path with
pathkeys, there is no way to create a partial path for a normal path.
This means that unless we create paths for all child-joins, we can not
create partial paths for appendrel comprising of child-joins, and thus
can not use parallel query right now. This may not be that bad, since
it would be more efficient to run each child-join in a separate
worker, rather than using multiple workers for a single child-join.
regression tests
----------------------
I observed that for small relations (1000 rows in each partition and
100 partitions), the size estimates in append relations and sum of
those in child relations are very different. As a result, the
extrapolated costs for PartitionJoinPaths as described above, are way
higher than costs of join of appends (or even append of joins if we
are to create paths for all child-joins). Thus with this approach, we
choose partition-wise join for large number of partitions with large
data (e.g. 1000 partitions with 1M rows each). These are certainly the
cases when partition-wise join is a big win. I have not tried to find
out a threshold above which partition-wise join gets chosen with above
approach, but it's going to be a larger threshold. That makes writing
regression tests difficult, as those will require large data. So, we
have to find a way so that we can test partition-wise join with
smaller data. There are few possibilities like 1. convert the fraction
of representative child-joins into GUC and setting it to 100% would
start choosing partition-wise joins for tables with a few hundred rows
per partition, like it did in earlier approach, 2. provide a way to
force partition-wise join whenever possible, by say costing
partition-wise joins much lesser than non-partition-wise join when a
GUC is set (e.g. enable_partition_wise_join with values always, never,
optimal or something like that).
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
mem_usage_func_wise_measurement_slabwise.patchbinary/octet-stream; name=mem_usage_func_wise_measurement_slabwise.patchDownload
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index b6ec32b..ba57118 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -47,6 +47,8 @@
#include "rewrite/rewriteManip.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
+#include "utils/memutils.h"
+#include "nodes/memnodes.h"
/* results of subquery_is_pushdown_safe */
@@ -3092,6 +3094,10 @@ generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
int num_dummy_parts;
ListCell *lc;
+ MemoryContextCounters mem_start;
+
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, __FUNCTION__);
+
/* Handle only join relations. */
if (!IS_JOIN_REL(rel))
return;
@@ -3211,6 +3217,8 @@ generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
if (sampled_children)
list_free(sampled_children);
+
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
}
/*****************************************************************************
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index b4220eb..ded1b7e 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -23,6 +23,7 @@
#include "optimizer/prep.h"
#include "optimizer/cost.h"
#include "utils/memutils.h"
+#include "nodes/memnodes.h"
static void make_rels_by_clause_joins(PlannerInfo *root,
@@ -766,6 +767,13 @@ populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
RelOptInfo *rel2, RelOptInfo *joinrel,
SpecialJoinInfo *sjinfo, List *restrictlist)
{
+ MemoryContextCounters mem_start;
+ char *label;
+
+ label = joinrel->reloptkind == RELOPT_OTHER_JOINREL ? "child_join_path_creation" : "parent_join_path_creation";
+
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, label);
+
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
@@ -910,6 +918,8 @@ populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
+
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, label);
}
/*
@@ -1322,6 +1332,10 @@ try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
int cnt_parts;
PartitionScheme part_scheme;
PartitionedJoin *partitioned_join;
+ MemoryContextCounters start_mem;
+
+ /* Start measuring memory */
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &start_mem, __FUNCTION__);
/* Guard against stack overflow due to overly deep partition hierarchy. */
check_stack_depth();
@@ -1415,6 +1429,7 @@ try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
List *join_appinfos;
List *appinfos1;
List *appinfos2;
+ MemoryContextCounters restrict_mem;
/* We should never try to join two overlapping sets of rels. */
Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
@@ -1431,6 +1446,7 @@ try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
appinfos2 = find_appinfos_by_relids(root, child_rel2->relids);
join_appinfos = list_concat(appinfos1, appinfos2);
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &restrict_mem, "restrictlist translation");
/*
* Construct restrictions applicable to the child join from
* those applicable to the parent join.
@@ -1439,6 +1455,8 @@ try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
(Node *)parent_restrictlist,
join_appinfos);
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &restrict_mem, "restrictlist translation");
+
/*
* Construct SpecialJoinInfo from parent join relations's
* SpecialJoinInfo.
@@ -1462,6 +1480,9 @@ try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
child_sjinfo, child_restrictlist);
}
+
+ /* Stop measuring memory and print the stats. */
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &start_mem, __FUNCTION__);
}
/*
@@ -1481,6 +1502,7 @@ add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
{
ListCell *lc;
RelOptInfo *child_joinrel = parent_joinrel->part_rels[child_id];
+ MemoryContextCounters rest_mem_usage;
Assert(IS_JOIN_REL(parent_joinrel));
@@ -1531,6 +1553,7 @@ add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
child_sjinfo = build_child_join_sjinfo(root, pj->sjinfo, appinfos1,
appinfos2);
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &rest_mem_usage, "restrictlist translation");
/*
* Construct restrictions applicable to the child join from
* those applicable to the parent join.
@@ -1539,6 +1562,8 @@ add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
(Node *) pj->restrictlist,
join_appinfos);
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &rest_mem_usage, "restrictlist translation");
+
/* The list is not needed anymore. */
list_free(join_appinfos);
@@ -1565,8 +1590,11 @@ static SpecialJoinInfo *
build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
List *append_rel_infos1, List *append_rel_infos2)
{
- SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo);
+ MemoryContextCounters mem_start;
+ SpecialJoinInfo *sjinfo;
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, __FUNCTION__);
+ sjinfo = copyObject(parent_sjinfo);
sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
append_rel_infos1);
sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
@@ -1580,6 +1608,8 @@ build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
sjinfo->semi_rhs_exprs = (List *) adjust_join_appendrel_attrs(root,
(Node *) sjinfo->semi_rhs_exprs,
append_rel_infos2);
+
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
return sjinfo;
}
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 3c0898a..e9ada93 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -55,6 +55,8 @@
#include "utils/selfuncs.h"
#include "utils/lsyscache.h"
#include "utils/syscache.h"
+#include "nodes/memnodes.h"
+#include "utils/memutils.h"
/* GUC parameters */
@@ -192,6 +194,9 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
Plan *top_plan;
ListCell *lp,
*lr;
+ MemoryContextCounters mem_start;
+
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, __FUNCTION__);
/* Cursor options may come from caller or from DECLARE CURSOR stmt */
if (parse->utilityStmt &&
@@ -432,6 +437,8 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
result->invalItems = glob->invalItems;
result->nParamExec = glob->nParamExec;
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
+
return result;
}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index 8510775..c27c59b 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -30,6 +30,8 @@
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
#include "utils/selfuncs.h"
+#include "utils/memutils.h"
+#include "nodes/memnodes.h"
typedef enum
@@ -3390,6 +3392,9 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
ParamPathInfo *new_ppi;
ParamPathInfo *old_ppi;
List *child_aris;
+ MemoryContextCounters mem_start;
+
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, __FUNCTION__);
/*
* If the path is not parameterized by parent of the given relation, it
@@ -3520,5 +3525,7 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
break;
}
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
+
return new_path;
}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index be08b6e..5d00c85 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -31,6 +31,8 @@
#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
#include "utils/rel.h"
+#include "nodes/memnodes.h"
+#include "utils/memutils.h"
typedef struct JoinHashEntry
@@ -598,9 +600,16 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
JoinType jointype)
{
- RelOptInfo *joinrel = makeNode(RelOptInfo);
+ RelOptInfo *joinrel;
List *join_appinfos;
+ MemoryContextCounters mem_start;
+ MemoryContextCounters tlist_mem;
+ MemoryContextCounters jlist_mem;
+
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, __FUNCTION__);
+
+ joinrel = makeNode(RelOptInfo);
joinrel->reloptkind = RELOPT_OTHER_JOINREL;
joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
joinrel->rows = 0;
@@ -659,16 +668,20 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/* Build targetlist */
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &tlist_mem, "targetlist");
build_joinrel_tlist(root, joinrel, outer_rel);
build_joinrel_tlist(root, joinrel, inner_rel);
/* Add placeholder variables. */
add_placeholders_to_joinrel(root, joinrel, outer_rel, inner_rel);
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &tlist_mem, "targetlist");
/* Translate joininfo. */
join_appinfos = find_appinfos_by_relids(root, joinrel->relids);
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &jlist_mem, "joininfo");
joinrel->joininfo = (List *) adjust_join_appendrel_attrs(root,
(Node *) parent_joinrel->joininfo,
join_appinfos);
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &jlist_mem, "joininfo");
/*
* Lateral relids referred in child join will be same as that referred in
@@ -700,6 +713,8 @@ build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
pfree(join_appinfos);
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
+
return joinrel;
}
diff --git a/src/backend/utils/mmgr/mcxt.c b/src/backend/utils/mmgr/mcxt.c
index 5cf388f..bd68a10 100644
--- a/src/backend/utils/mmgr/mcxt.c
+++ b/src/backend/utils/mmgr/mcxt.c
@@ -514,7 +514,7 @@ MemoryContextStatsDetail(MemoryContext context, int max_children)
* Print this context if print is true, but in any case accumulate counts into
* *totals (if given).
*/
-static void
+void
MemoryContextStatsInternal(MemoryContext context, int level,
bool print, int max_children,
MemoryContextCounters *totals)
@@ -1181,3 +1181,29 @@ pnstrdup(const char *in, Size len)
out[len] = '\0';
return out;
}
+
+void
+MemoryContextFuncStatsStart(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *label)
+{
+ memset(start_counts, 0, sizeof(*start_counts));
+ MemoryContextStatsInternal(context, 0, false, 100, start_counts);
+}
+
+void
+MemoryContextFuncStatsEnd(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *label)
+{
+ MemoryContextCounters end_counts;
+ Size start_used_space = start_counts->totalspace - start_counts->freespace;
+ Size end_used_space;
+
+ memset(&end_counts, 0, sizeof(end_counts));
+ MemoryContextStatsInternal(context, 0, false, 100, &end_counts);
+ end_used_space = end_counts.totalspace - end_counts.freespace;
+
+ elog(NOTICE, "%s,%s,%zu,%zu,%ld", label, context->name,
+ start_used_space, end_used_space, end_used_space - start_used_space);
+}
diff --git a/src/include/utils/memutils.h b/src/include/utils/memutils.h
index e6334a2..6a3ed55 100644
--- a/src/include/utils/memutils.h
+++ b/src/include/utils/memutils.h
@@ -122,6 +122,12 @@ extern MemoryContext MemoryContextCreate(NodeTag tag, Size size,
MemoryContextMethods *methods,
MemoryContext parent,
const char *name);
+extern void MemoryContextFuncStatsStart(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *func_label);
+extern void MemoryContextFuncStatsEnd(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *func_label);
/*
pg_dp_join_v5.patchbinary/octet-stream; name=pg_dp_join_v5.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 691658f..287c7d5 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -770,7 +770,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
deparse_expr_cxt context;
/* We handle relations for foreign tables and joins between those */
- Assert(rel->reloptkind == RELOPT_JOINREL ||
+ Assert(IS_JOIN_REL(rel) ||
rel->reloptkind == RELOPT_BASEREL ||
rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
@@ -824,7 +824,7 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
/* For a join relation use the input tlist */
deparseExplicitTargetList(tlist, retrieved_attrs, context);
@@ -852,8 +852,7 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
* Construct FROM clause
*/
appendStringInfoString(buf, " FROM ");
- deparseFromExprForRel(buf, root, foreignrel,
- (foreignrel->reloptkind == RELOPT_JOINREL),
+ deparseFromExprForRel(buf, root, foreignrel, IS_JOIN_REL(foreignrel),
context->params_list);
}
@@ -988,7 +987,7 @@ deparseLockingClause(deparse_expr_cxt *context)
appendStringInfoString(buf, " FOR UPDATE");
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(rel))
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
else
@@ -1024,8 +1023,7 @@ deparseLockingClause(deparse_expr_cxt *context)
}
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL &&
- rc->strength != LCS_NONE)
+ if (IS_JOIN_REL(rel) && rc->strength != LCS_NONE)
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
}
@@ -1162,7 +1160,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
RelOptInfo *rel_o = fpinfo->outerrel;
RelOptInfo *rel_i = fpinfo->innerrel;
@@ -1867,7 +1865,7 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL);
+ bool qualify_col = IS_JOIN_REL(context->foreignrel);
if (bms_is_member(node->varno, context->foreignrel->relids) &&
node->varlevelsup == 0)
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index daf0438..594292a 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -1170,7 +1170,7 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
/* For a join relation, get the conditions from fdw_private structure */
remote_conds = fpinfo->remote_conds;
@@ -1228,7 +1228,7 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2505,7 +2505,7 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
fdw_scan_tlist = NIL;
@@ -2586,7 +2586,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind != RELOPT_JOINREL)
+ else if (!IS_JOIN_REL(foreignrel))
{
/* Clamp retrieved rows estimates to at most foreignrel->tuples. */
retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index 1a60563..dc2b34b 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -20,6 +20,7 @@
#include "access/nbtree.h"
#include "access/sysattr.h"
#include "catalog/dependency.h"
+#include "catalog/heap.h"
#include "catalog/indexing.h"
#include "catalog/objectaddress.h"
#include "catalog/partition.h"
@@ -36,8 +37,10 @@
#include "nodes/nodeFuncs.h"
#include "nodes/parsenodes.h"
#include "optimizer/clauses.h"
+#include "optimizer/cost.h"
#include "optimizer/planmain.h"
#include "optimizer/var.h"
+#include "rewrite/rewriteManip.h"
#include "storage/lmgr.h"
#include "utils/array.h"
#include "utils/builtins.h"
@@ -2419,6 +2422,64 @@ make_range_bound(PartitionKey key, List *val, bool inclusive, bool lower)
}
/*
+ * Return a copy of input BoundCollection structure containg nparts number of
+ * partitions. The data types of bounds are described by given partition key
+ * specificiation.
+ */
+static BoundCollection
+copy_bounds(BoundCollection src_bounds, PartitionKey key, int nparts)
+{
+ BoundCollection dst_bounds;
+ int i;
+
+ dst_bounds = (BoundCollection) palloc(sizeof(BoundCollectionData));
+
+ if (src_bounds->listinfo)
+ {
+ ListInfo *dst_li = (ListInfo *) palloc(sizeof(ListInfo));
+ ListInfo *src_li = src_bounds->listinfo;
+
+ Assert(!src_bounds->rangeinfo);
+ dst_bounds->rangeinfo = NULL;
+
+ /* Copy the ListInfo structure. */
+ dst_li->nvalues = src_li->nvalues;
+ dst_li->has_null = src_li->has_null;
+ dst_li->null_index = src_li->null_index;
+
+ dst_li->values = (Datum *) palloc(sizeof(Datum) * dst_li->nvalues);
+ dst_li->indexes = (int *) palloc(sizeof(int) * dst_li->nvalues);
+ for (i = 0; i < dst_li->nvalues; i++)
+ {
+ dst_li->values[i] = datumCopy(src_li->values[i],
+ key->tcinfo->typbyval[0],
+ key->tcinfo->typlen[0]);
+ dst_li->indexes[i] = src_li->indexes[i];
+ }
+
+ dst_bounds->listinfo = dst_li;
+ }
+ else
+ {
+ RangeInfo *dst_ri = (RangeInfo *) palloc(sizeof(RangeInfo));
+ RangeInfo *src_ri = src_bounds->rangeinfo;
+
+ Assert(!src_bounds->listinfo && src_bounds->rangeinfo);
+ dst_bounds->listinfo = NULL;
+
+ /* Copy RangeInfo structure. */
+ dst_ri = (RangeInfo *) palloc(sizeof(RangeInfo));
+ dst_ri->ranges = (PartitionRange **) palloc(sizeof(PartitionRange *) * nparts);
+ for (i = 0; i < nparts; i++)
+ dst_ri->ranges[i] = copy_range(src_ri->ranges[i], key);
+
+ dst_bounds->rangeinfo = dst_ri;
+ }
+
+ return dst_bounds;
+}
+
+/*
* Make and return a copy of input PartitionRange.
*/
static PartitionRange *
@@ -2654,3 +2715,168 @@ tuple_leftof_bound(PartitionKey key, Datum *tuple, PartitionRangeBound *bound)
return cmpval < 0;
}
+
+/*
+ * find_partition_scheme
+ * Find the "canonical" partition scheme for the given base table.
+ *
+ * The function searches the list of canonical partition schemes for one that
+ * exactly matches the partitioning properties of the given relation. If it
+ * does not find one, the function creates a canonical partition scheme
+ * structure and adds it to the list.
+ *
+ * For an unpartitioned table, it returns NULL.
+ */
+
+extern PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * It suffices to check the OID of support function as it always has
+ * two arguments and returns boolean. For types, it suffices to match
+ * the type id, mod and collation; len, byval and align are depedent on
+ * the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->tcinfo->typid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->tcinfo->typmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->tcinfo->typcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->bounds,
+ part_scheme->bounds, nparts))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->bounds = copy_bounds(part_desc->bounds, part_key,
+ part_scheme->nparts);
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ part_scheme->partopfamily[cnt_pks] = part_key->partopfamily[cnt_pks];
+ part_scheme->partopcintype[cnt_pks] = part_key->partopcintype[cnt_pks];
+ part_scheme->key_types[cnt_pks] = part_key->tcinfo->typid[cnt_pks];
+ part_scheme->key_typmods[cnt_pks] = part_key->tcinfo->typmod[cnt_pks];
+ part_scheme->key_collations[cnt_pks] = part_key->tcinfo->typcoll[cnt_pks];
+ }
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_key_exprs
+ * Collect partition key expressions for a given base relation.
+ *
+ * The function converts single column partition keys into corresponding Var
+ * nodes. It restamps Var nodes in partition key expressions by given varno.
+ * The partition key expressions are returned as an array of Lists to be stored
+ * in RelOptInfo of the base relation.
+ */
+extern List **
+build_baserel_partition_key_exprs(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (lc == NULL)
+ elog(ERROR, "wrong number of partition key expressions");
+
+ /* Re-stamp the expressions with given varno. */
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 242d6d2..75c95e4 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -721,7 +721,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
{
ListCell *lc;
- Assert(joinrel->reloptkind == RELOPT_JOINREL);
+ Assert(IS_JOIN_REL(joinrel));
foreach(lc, joinrel->pathlist)
{
@@ -786,7 +786,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->outerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->outerjoinpath = foreign_path->fdw_outerpath;
}
@@ -795,7 +795,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->innerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->innerjoinpath = foreign_path->fdw_outerpath;
}
diff --git a/src/backend/optimizer/README b/src/backend/optimizer/README
index 775bcc3..f203dc5 100644
--- a/src/backend/optimizer/README
+++ b/src/backend/optimizer/README
@@ -974,3 +974,56 @@ be desirable to postpone the Gather stage until as near to the top of the
plan as possible. Expanding the range of cases in which more work can be
pushed below the Gather (and costing them accurately) is likely to keep us
busy for a long time to come.
+
+Partition-wise joins
+--------------------
+A join between two similarly partitioned tables can be broken down into joins
+between their matching partitions if there exists an equi-join condition
+between the partition keys of the joining tables. The equi-join between
+partition keys implies that for a given row in a given partition of a given
+partitioned table, its joining row, if exists, should exist only in the
+matching partition of the other partitioned table; no row from non-matching
+partitions in the other partitioned table can join with the given row from the
+first table. This condition allows the join between partitioned table to be
+broken into joins between the matching partitions. The resultant join is
+partitioned in the same way as the joining relations, thus allowing an N-way
+join between similarly partitioned tables having equi-join condition between
+their partition keys to be broken down into N-way joins between their matching
+partitions. This technique of breaking down a join between partition tables
+into join between their partitions is called partition-wise join. We will use
+term "partitioned relation" for both partitioned table as well as join between
+partitioned tables which can use partition-wise join technique.
+
+Partitioning properties of a partitioned table are stored in
+PartitionSchemeData structure. Planner maintains a list of canonical partition
+schemes (distinct PartitionSchemeData objects) so that any two partitioned
+relations with same partitioning scheme share the same PartitionSchemeData
+object. This reduces memory consumed by PartitionSchemeData objects and makes
+it easy to compare the partition schemes of joining relations. RelOptInfos of
+partitioned relations hold partition key expressions and the RelOptInfos of
+the partition relations of that relation.
+
+Partition-wise joins are planned in two phases
+
+1. First phase creates the RelOptInfos for joins between matching partitions
+and creates join paths for those using the same techniques described above.
+The number of paths created for a child-join i.e. join between partitions is
+same as the number of paths created for join between parents. That number grows
+exponentially with the number of base relations being joined. The time and
+memory consumed to create paths for each child-join will be proporional to the
+number of partitions. This will not scale well with thousands of partitions.
+Instead of that we estimate partition-wise join cost based on the costs of
+sampled child-joins. We choose child-joins with higher sizes to have realistic
+estimates. If the number of sampled child-joins is same as the number of live
+child-joins, we create append paths as we know costs of all required
+child-joins. Otherwise we create PartitionJoinPaths with cost estimates based
+on the costs of sampled child-joins. While creating append paths or
+PartitionJoin paths we create paths for all the different possible
+parameterizations and pathkeys available in the sampled child-joins.
+
+2. If PartitionJoinPath emerges as the best possible path, we create paths for
+each unsampled child-join and choose the cheapest one with same
+parameterization or pathkeys as the PartitionJoinPath. This path is converted
+into a plan and all the child-join plans are combined using an Append or
+MergeAppend plan as appropriate. We use a fresh memory context for planning
+each unsampled child-join, thus reducing memory consumption.
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 99b6bc8..fbacb3c 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -18,8 +18,10 @@
#include <limits.h>
#include <math.h>
+#include "miscadmin.h"
#include "access/sysattr.h"
#include "access/tsmapi.h"
+#include "catalog/partition.h"
#include "catalog/pg_class.h"
#include "catalog/pg_operator.h"
#include "catalog/pg_proc.h"
@@ -44,6 +46,7 @@
#include "parser/parsetree.h"
#include "rewrite/rewriteManip.h"
#include "utils/lsyscache.h"
+#include "utils/rel.h"
/* results of subquery_is_pushdown_safe */
@@ -93,8 +96,8 @@ static void set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
static void set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
static void generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels,
- List *all_child_pathkeys);
+ List *live_childrels, List *all_child_pathkeys,
+ bool partition_join_path);
static Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
RelOptInfo *rel,
Relids required_outer);
@@ -126,6 +129,8 @@ static void subquery_push_qual(Query *subquery,
static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels, bool partition_join_path);
/*
@@ -868,6 +873,30 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ Oid *part_oids = NULL;
+ int nparts = 0;
+
+ /* Fetch the number of partitions of a partitioned table and their Oids. */
+ if (rel->part_scheme)
+ {
+ RangeTblEntry *rte = root->simple_rte_array[rel->relid];
+
+ /*
+ * We need not lock the relation since it was already locked, either by
+ * the rewriter or when expand_inherited_rtentry() added it to the
+ * query's rangetable.
+ */
+ Relation relation = heap_open(rte->relid, NoLock);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+
+ part_oids = part_desc->oids;
+ nparts = part_desc->nparts;
+
+ Assert(part_oids && nparts > 0);
+
+ rel->part_rels = (RelOptInfo **)palloc0(sizeof(RelOptInfo *) * nparts);
+ heap_close(relation, NoLock);
+ }
/*
* Initialize to compute size estimates for whole append relation.
@@ -899,6 +928,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Node *childqual;
ListCell *parentvars;
ListCell *childvars;
+ int cnt_parts;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -912,8 +942,101 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* add_base_rels_to_query.
*/
childrel = find_base_rel(root, childRTindex);
+
+ /*
+ * Recursively save topmost parent's relid in RelOptInfos of
+ * partitions.
+ */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
+ /*
+ * For two partitioned tables with the same partitioning scheme, it is
+ * assumed that the Oids of matching partitions from both the tables
+ * are placed at the same position in the array of partition oids in
+ * respective partition descriptors. Saving the RelOptInfo of a
+ * partition in the same location as its Oid makes it easy to find the
+ * RelOptInfos of matching partitions for partition-wise join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+
+ /*
+ * Note: we could compute appropriate attr_needed data for the child's
+ * variables, by transforming the parent's attr_needed through the
+ * translated_vars mapping. However, currently there's no need
+ * because attr_needed is only examined for base relations not
+ * otherrels. So we just leave the child's attr_needed empty.
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for buiding pair-wise
+ * join relations. Partition tables should have same layout as the
+ * parent table and hence should not need any translation. But rest of
+ * the code still uses inheritance mechanism. So do we here.
+ */
+ if (rel->part_scheme)
+ {
+ AttrNumber attno;
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /* Parent Var translates to child Var. */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
+ }
+
+ /*
+ * Copy/Modify targetlist. Partition-wise join technique may join this
+ * child with a child of another partitioned table, such that this
+ * child forms the nullable side of the outer join. In such a case, we
+ * will need the targetlist of this child, even if it's deemed empty.
+ * Hence set the targetlist before bailing out in case the child is
+ * proven empty.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ list_make1(appinfo));
+
/*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
@@ -931,7 +1054,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childquals = get_all_actual_clauses(rel->baserestrictinfo);
childquals = (List *) adjust_appendrel_attrs(root,
(Node *) childquals,
- appinfo);
+ list_make1(appinfo));
childqual = eval_const_expressions(root, (Node *)
make_ands_explicit(childquals));
if (childqual && IsA(childqual, Const) &&
@@ -960,24 +1083,11 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying join quals. */
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
- appinfo);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo);
+ list_make1(appinfo));
/*
* We have to make child entries in the EquivalenceClass data
@@ -992,14 +1102,6 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
- * Note: we could compute appropriate attr_needed data for the child's
- * variables, by transforming the parent's attr_needed through the
- * translated_vars mapping. However, currently there's no need
- * because attr_needed is only examined for base relations not
- * otherrels. So we just leave the child's attr_needed empty.
- */
-
- /*
* If parallelism is allowable for this query in general, see whether
* it's allowable for this childrel in particular. But if we've
* already decided the appendrel is not parallel-safe as a whole,
@@ -1080,6 +1182,16 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ if (!rel->part_rels[cnt_parts])
+ elog(ERROR, "could not find the RelOptInfo of a partition with oid %u",
+ part_oids[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
@@ -1122,19 +1234,11 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
- * Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * Generate access paths for each member relation and remember the
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
@@ -1142,7 +1246,6 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -1177,6 +1280,64 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ /* Add Append/MergeAppend paths to the "append" relation. */
+ add_paths_to_append_rel(root, rel, live_childrels, false);
+}
+
+/*
+ * add_paths_to_append_rel
+ * Generate Append/MergeAppend paths for given "append" relation. An
+ * "append" relation can be a base parent relation or a join between
+ * partitioned tables.
+ *
+ * The function collects all parameterizations and orderings supported by the
+ * non-dummy children. For every such parameterization or ordering, it creates
+ * an append path collecting one path from each non-dummy child with given
+ * parameterization or ordering. Similarly it collects partial paths from
+ * non-dummy children to create partial append paths.
+ */
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels, bool partition_join_path)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * While creating PartitionJoinPath, we sample paths from only a few child
+ * relations. Even if all of sampled children have partial paths, it's not
+ * guaranteed that all the unsampled children will have partial paths.
+ * Hence we do not create partial PartitionJoinPaths.
+ */
+ partial_subpaths_valid = !partition_join_path ? true : false;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (live_childrels == NIL)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
@@ -1267,7 +1428,17 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(rel, subpaths,
+ NULL);
+ else
+ path = (Path *) create_append_path(rel, subpaths, NULL, 0);
+
+ add_path(rel, path);
+ }
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1278,6 +1449,8 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
ListCell *lc;
int parallel_workers = 0;
+ Assert(!partition_join_path);
+
/*
* Decide on the number of workers to request for this append path.
* For now, we just use the maximum value from among the members. It
@@ -1304,7 +1477,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
*/
if (subpaths_valid)
generate_mergeappend_paths(root, rel, live_childrels,
- all_child_pathkeys);
+ all_child_pathkeys, partition_join_path);
/*
* Build Append paths for each parameterization seen among the child rels.
@@ -1345,8 +1518,16 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(rel, subpaths, required_outer);
+ else
+ path = (Path *) create_append_path(rel, subpaths, required_outer, 0);
+
+ add_path(rel, path);
+ }
}
}
@@ -1376,7 +1557,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
static void
generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *live_childrels,
- List *all_child_pathkeys)
+ List *all_child_pathkeys, bool partition_join_path)
{
ListCell *lcp;
@@ -1387,6 +1568,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *total_subpaths = NIL;
bool startup_neq_total = false;
ListCell *lcr;
+ Path *path;
/* Select the child paths for this ordering... */
foreach(lcr, live_childrels)
@@ -1434,17 +1616,29 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
}
/* ... and build the MergeAppend paths */
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- startup_subpaths,
- pathkeys,
- NULL));
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path_with_pathkeys(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+
if (startup_neq_total)
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- total_subpaths,
- pathkeys,
- NULL));
+ {
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path_with_pathkeys(root,
+ rel,
+ total_subpaths,
+ pathkeys, NULL);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ total_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+ }
}
}
@@ -2188,6 +2382,10 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
+ * join_search_one_level. Similarly, create append paths for joinrels
+ * which used partition-wise join technique. We can not do this
+ * earlier because the paths can get added to a relation representing
+ * join between children at multiple times within
* join_search_one_level. After that, we're done creating paths for
* the joinrel, so run set_cheapest().
*/
@@ -2195,6 +2393,9 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
{
rel = (RelOptInfo *) lfirst(lc);
+ /* Create Append/MergeAppend paths for partition-wise joins. */
+ generate_partition_wise_join_paths(root, rel);
+
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
@@ -2858,6 +3059,160 @@ remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel)
}
}
+/* Fraction of to base cost on. Probably we should turn this into a GUC? */
+#define FRACTION_PARTS_TO_PLAN 0.01
+
+/*
+ * generate_partition_wise_join_paths
+ * Create paths representing partition-wise join for given partitioned
+ * join relation.
+ *
+ * The number of paths created for a child-join is same as the number of paths
+ * created for join between parents. That number grows exponentially with the
+ * number of base relations being joined. The time and memory consumed to
+ * create paths for each child-join will be proporional to the number of
+ * partitions. This will not scale well with thousands of partitions. Instead
+ * of that we estimate partition-wise join cost based on the costs of sampled
+ * child-joins. We choose child-joins with higher sizes to have realistic
+ * estimates.
+ *
+ * This must be called after we have considered all joining orders for
+ * parent-join, and required child-joins (Otherwise, add_path might delete a
+ * path that some Append/MergeAppend path has a reference to.)
+ */
+void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *sampled_children = NIL;
+ List *sampled_child_nos = NIL;
+ int cnt_part;
+ int num_part_to_plan;
+ int num_parts;
+ bool partition_join_path = false;
+ int num_dummy_parts;
+ ListCell *lc;
+
+ /* Handle only join relations. */
+ if (!IS_JOIN_REL(rel))
+ return;
+
+ /*
+ * If partition-wise join technique was not used for any of the join
+ * orders, the join is not partitioned. Reset the partitioning scheme.
+ */
+ if (!rel->part_rels)
+ rel->part_scheme = NULL;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || IS_DUMMY_REL(rel))
+ return;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ num_parts = rel->part_scheme->nparts;
+
+ /* Calculate number of child-joins to sample. */
+ num_part_to_plan = num_parts * FRACTION_PARTS_TO_PLAN;
+ if (num_part_to_plan < 1)
+ num_part_to_plan = 1;
+
+ /* Sample the child-joins with higher sizes. */
+ for (cnt_part = 0; cnt_part < num_parts; cnt_part++)
+ {
+ RelOptInfo *child_rel = rel->part_rels[cnt_part];
+ ListCell *insert_after;
+
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+ insert_after = NULL;
+
+ /*
+ * Add this relation to the list of samples ordered by the increasing
+ * number of rows at appropriate place.
+ */
+ foreach (lc, sampled_child_nos)
+ {
+ int child_no = lfirst_int(lc);
+ RelOptInfo *old_childrel = rel->part_rels[child_no];
+
+ /*
+ * Keep track of child with lowest number of rows but higher than the
+ * that of the child being inserted. Insert the child before a
+ * child with highest number of rows lesser than it.
+ */
+ if (child_rel->rows <= old_childrel->rows)
+ insert_after = lc;
+ else
+ break;
+ }
+
+ /*
+ * If we have collected required number of child-joins and current
+ * child-join has lesser number of rows than all the child-joins
+ * collected so far, ignore it in this phase.
+ */
+ if (insert_after == list_tail(sampled_child_nos) &&
+ list_length(sampled_child_nos) == num_part_to_plan)
+ continue;
+
+ if (insert_after)
+ lappend_cell_int(sampled_child_nos, insert_after, cnt_part);
+ else
+ sampled_child_nos = lcons_int(cnt_part, sampled_child_nos);
+
+ /* Trim down list to the required number of children. */
+ if (list_length(sampled_child_nos) > num_part_to_plan)
+ {
+ /*
+ * List is trimmed every time it grows after adding one child. So,
+ * it can have at most one extra element.
+ */
+ Assert(list_length(sampled_child_nos) == num_part_to_plan + 1);
+
+ list_delete_cell(sampled_child_nos,
+ list_nth_cell(sampled_child_nos,
+ list_length(sampled_child_nos) - 1),
+ list_nth_cell(sampled_child_nos,
+ list_length(sampled_child_nos) - 2));
+ }
+
+ Assert(list_length(sampled_child_nos) <= num_part_to_plan);
+ }
+
+ /* Create paths for all the sampled child-joins. */
+ foreach (lc, sampled_child_nos)
+ {
+ int child_no = lfirst_int(lc);
+
+ /* Create paths for this child. */
+ add_paths_to_child_joinrel(root, rel, child_no);
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+ sampled_children = lappend(sampled_children, rel->part_rels[child_no]);
+ }
+
+ /*
+ * If the number of samples is same as the number of live children, an
+ * append path will do. Otherwise, we will cost the partition-wise join
+ * based on the sampled children using PartitionJoinPath.
+ */
+ if (num_part_to_plan < num_parts - num_dummy_parts)
+ partition_join_path = true;
+
+ /* Add paths for partition-wise join based on the sampled children. */
+ add_paths_to_append_rel(root, rel, sampled_children, partition_join_path);
+
+ if (sampled_children)
+ list_free(sampled_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
*****************************************************************************/
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 2a49639..a23da1c 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,7 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
typedef struct
{
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index 0e50ad5..fc40b69 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2062,7 +2062,7 @@ add_child_rel_equivalences(PlannerInfo *root,
child_expr = (Expr *)
adjust_appendrel_attrs(root,
(Node *) cur_em->em_expr,
- appinfo);
+ list_make1(appinfo));
/*
* Transform em_relids to match. Note we do *not* do
@@ -2366,6 +2366,8 @@ eclass_useful_for_merging(PlannerInfo *root,
/* If specified rel is a child, we must consider the topmost parent rel */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->top_parent_relids;
else
relids = rel->relids;
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index cc7384f..fae15de 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -25,9 +25,19 @@
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+/*
+ * Paths parameterized by the parent can be considered to be parameterized by
+ * any of its child.
+ */
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
@@ -132,6 +142,19 @@ add_paths_to_joinrel(PlannerInfo *root,
foreach(lc, root->join_info_list)
{
SpecialJoinInfo *sjinfo = (SpecialJoinInfo *) lfirst(lc);
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between child relations, even if there is a SpecialJoinInfo node for
+ * the join between the topmost parents. Hence while calculating Relids
+ * set representing the restriction, consider relids of topmost parent
+ * of partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
/*
* SJ is relevant to this join if we have some part of its RHS
@@ -140,16 +163,16 @@ add_paths_to_joinrel(PlannerInfo *root,
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo->min_righthand))
+ bms_overlap(joinrelids, sjinfo->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo->min_lefthand));
@@ -279,6 +302,24 @@ try_nestloop_path(PlannerInfo *root,
JoinCostWorkspace workspace;
/*
+ * For a join between child relations, if the inner path is parameterized
+ * by the parent of the outer relation, it can be considered to be
+ * parameterized by the outer relation. We will be able to create a
+ * nestloop join path with inner relation parameterized by the outer
+ * relation by translating the inner path to be parameterized by the outer
+ * child relation.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_by_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..b4220eb 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -14,9 +14,14 @@
*/
#include "postgres.h"
+#include "miscadmin.h"
+#include "catalog/partition.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
@@ -32,7 +37,20 @@ static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
-
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static SpecialJoinInfo * build_child_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1,
+ List *append_rel_infos2);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
/*
* join_search_one_level
@@ -724,6 +742,30 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Add paths joining given input relations to the given joinrel. The
+ * SpecialJoinInfo provides details about the join and the restrictlist
+ * contains the join clauses and the other clauses applicable for given pair
+ * of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
@@ -868,13 +910,8 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
-
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
@@ -1249,3 +1286,462 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
}
return false;
}
+
+/*
+ * Assess whether join between given two partitioned relations can be broken
+ * down into joins between matching partitions; a technique called
+ * "partition-wise join"
+ *
+ * Partition-wise join is possible when a. Joining relations have same
+ * partitioning scheme b. There exists an equi-join between the partition keys
+ * of the two relations.
+ *
+ * Partition-wise join is planned in three phases (details: optimizer/README.)
+ *
+ * 1. Create the RelOptInfos for joins between matching partitions i.e
+ * child-joins and estimate sizes of those. This function is responsible for
+ * this phase.
+ *
+ * 2. Add paths representing partition-wise join. The second phase is
+ * implemented by generate_partition_wise_join_paths(). In order to save time
+ * and memory consumed in creating paths for every child-join, we create paths
+ * for only few child-joins. Paths for remaining child-joins are created in the
+ * next phase.
+ *
+ * 3. Create merge/append plan to combining plans for every child-join.
+ *
+ * The RelOptInfo, SpecialJoinInfo and restrictlist for each child join are
+ * obtained by translating the respective parent join structures.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ PartitionScheme part_scheme;
+ PartitionedJoin *partitioned_join;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If any of the joining parent relations is proven empty, either the join
+ * will be empty (INNER join) or will have the inner side all nullified. We
+ * take care of such cases when creating join paths for parent relations.
+ * Nothing to be done here. Also, nothing to do, if the parent join is
+ * proven empty.
+ */
+ if (IS_DUMMY_REL(rel1) || IS_DUMMY_REL(rel2) || IS_DUMMY_REL(joinrel))
+ return;
+
+ /*
+ * Partitioning scheme in join relation indicates a possibilty that the
+ * join may be partitioned, but it's not necessary that every pair of
+ * joining relations can use partition-wise join technique. If one of
+ * joining relations turns out to be unpartitioned, this pair of joining
+ * relations can not use partition-wise join technique.
+ */
+ if (!rel1->part_scheme || !rel2->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, this pair of joining relations can not use
+ * partition-wise technique.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ /*
+ * The partition scheme of the join relation should match that of the
+ * joining relations.
+ */
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ /* We should have RelOptInfos of the partitions available. */
+ Assert(rel1->part_rels && rel2->part_rels);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = part_scheme->nparts;
+
+ /*
+ * We do not store information about valid pairs of joining child
+ * relations. The pair of joining relations for a child-join can be
+ * derived by valid pairs of joining parent relations. Amongst the valid
+ * pairs of parent joining relations, only those which result in
+ * partitioned join matter for partition-wise join. Remember those so that
+ * we can use them for creating paths child-joins for PartitionJoinPaths
+ * later.
+ */
+ partitioned_join = (PartitionedJoin *) palloc(sizeof(PartitionedJoin));
+ partitioned_join->rel1 = rel1;
+ partitioned_join->rel2 = rel2;
+ partitioned_join->restrictlist = parent_restrictlist;
+ partitioned_join->sjinfo = copyObject(parent_sjinfo);
+ joinrel->partitioned_joins = lappend(joinrel->partitioned_joins,
+ partitioned_join);
+
+ elog(DEBUG3, "join between relations %s and %s is considered for partition-wise join.",
+ bmsToString(rel1->relids), bmsToString(rel2->relids));
+
+ /* We are done if child RelOptInfos are already created. */
+ if (joinrel->part_rels)
+ return;
+
+ /* Create all the child RelOptInfos. */
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create child join relations for this partitioned join. While doing so,
+ * we estimate sizes of these child join relations. These estimates are
+ * used to find the representative child relations used for costing the
+ * partition-wise join later.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ RelOptInfo *child_joinrel;
+ List *join_appinfos;
+ List *appinfos1;
+ List *appinfos2;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ Assert (!joinrel->part_rels[cnt_parts]);
+
+ child_joinrel = build_child_join_rel(root, child_rel1, child_rel2,
+ joinrel, parent_sjinfo->jointype);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ /* Get parent-child mapping for translating nodes. */
+ appinfos1 = find_appinfos_by_relids(root, child_rel1->relids);
+ appinfos2 = find_appinfos_by_relids(root, child_rel2->relids);
+ join_appinfos = list_concat(appinfos1, appinfos2);
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = (List *) adjust_join_appendrel_attrs(root,
+ (Node *)parent_restrictlist,
+ join_appinfos);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, parent_sjinfo, appinfos1,
+ appinfos2);
+
+ /*
+ * Set estimates of the child-joinrel's size.
+ */
+ set_joinrel_size_estimates(root, child_joinrel, child_rel1, child_rel2,
+ child_sjinfo, child_restrictlist);
+
+ /* The list is not needed anymore. */
+ list_free(join_appinfos);
+
+ /*
+ * If the child relations themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+ }
+}
+
+/*
+ * add_paths_to_child_join
+ *
+ * Add paths to 'child_id'th child of given parent join relation.
+ *
+ * The function creates paths for given child join by considering join between
+ * corresponding children of every pair of joining parent relation which
+ * produces partitioned join. Since we create paths only for sampled
+ * child-joins, either of the children being joined may not have paths. In that
+ * case, this function is called recursively to populate paths for those.
+ */
+void
+add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
+ int child_id)
+{
+ ListCell *lc;
+ RelOptInfo *child_joinrel = parent_joinrel->part_rels[child_id];
+
+ Assert(IS_JOIN_REL(parent_joinrel));
+
+ /* If this child relation already has paths, nothing to do. */
+ if (child_joinrel->cheapest_total_path)
+ return;
+
+ /* A dummy relation will have a dummy path as the cheapest path. */
+ Assert(!is_dummy_rel(child_joinrel));
+
+ /*
+ * For every partitioned join order, calculate paths for the joining
+ * child relations and then calculate paths for given child.
+ */
+ foreach (lc, parent_joinrel->partitioned_joins)
+ {
+ PartitionedJoin *pj = lfirst(lc);
+ RelOptInfo *rel1 = pj->rel1;
+ RelOptInfo *rel2 = pj->rel2;
+ RelOptInfo *child_rel1 = rel1->part_rels[child_id];
+ RelOptInfo *child_rel2 = rel2->part_rels[child_id];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ List *join_appinfos;
+ List *appinfos1;
+ List *appinfos2;
+
+ /*
+ * Add paths to joining relation if it is a join itself.
+ * Paths for child base relations are created in
+ * set_append_rel_pathlist().
+ */
+ if (IS_JOIN_REL(pj->rel1))
+ add_paths_to_child_joinrel(root, rel1, child_id);
+
+ if (IS_JOIN_REL(pj->rel2))
+ add_paths_to_child_joinrel(root, rel2, child_id);
+
+ /* Get parent-child mapping for translating nodes. */
+ appinfos1 = find_appinfos_by_relids(root, child_rel1->relids);
+ appinfos2 = find_appinfos_by_relids(root, child_rel2->relids);
+ join_appinfos = list_concat(appinfos1, appinfos2);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, pj->sjinfo, appinfos1,
+ appinfos2);
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) pj->restrictlist,
+ join_appinfos);
+
+ /* The list is not needed anymore. */
+ list_free(join_appinfos);
+
+ /* Add paths for child join. */
+ populate_joinrel_with_paths(root, rel1->part_rels[child_id],
+ rel2->part_rels[child_id], child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * In case the child is partitioned, add partition-wise join paths for
+ * it.
+ */
+ generate_partition_wise_join_paths(root, child_joinrel);
+ }
+
+ set_cheapest(child_joinrel);
+}
+
+/*
+ * Construct the SpecialJoinInfo for the join between children by translating
+ * SpecialJoinInfo for the join between parents.
+ */
+static SpecialJoinInfo *
+build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ List *append_rel_infos1, List *append_rel_infos2)
+{
+ SpecialJoinInfo *sjinfo = copyObject(parent_sjinfo);
+
+ sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
+ append_rel_infos1);
+ sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
+ append_rel_infos2);
+ sjinfo->syn_lefthand = adjust_child_relids(sjinfo->syn_lefthand,
+ append_rel_infos1);
+ sjinfo->syn_righthand = adjust_child_relids(sjinfo->syn_righthand,
+ append_rel_infos2);
+
+ /* Replace the Var nodes of parent with those of children in expressions. */
+ sjinfo->semi_rhs_exprs = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ append_rel_infos2);
+ return sjinfo;
+}
+
+/*
+ * Replace parent relids by child relids in the given relid set.
+ */
+Relids
+adjust_child_relids(Relids relids, List *append_rel_infos)
+{
+ ListCell *lc;
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ /* Remove parent, add child*/
+ if (bms_is_member(appinfo->parent_relid, relids))
+ {
+ relids = bms_del_member(relids, appinfo->parent_relid);
+ relids = bms_add_member(relids, appinfo->child_relid);
+ }
+ }
+ return relids;
+}
+
+/*
+ * Returns true if there exists an equi-join condition for each pair of
+ * partition key from given relations being joined.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ /*
+ * This function should be called when the joining relations have same
+ * partitioning scheme.
+ */
+ Assert(rel1->part_scheme == rel2->part_scheme);
+ Assert(part_scheme);
+
+ num_pks = part_scheme->partnatts;
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip clauses which can not be used for a join. */
+ if (!rinfo->can_join)
+ continue;
+
+ /* Skip clauses which are not equality conditions. */
+ if (rinfo->hashjoinoperator == InvalidOid && !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+
+ /* Match the operands to the relation. */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ /*
+ * If the clause refers to different partition keys from
+ * both relations, it can not be used for partition-wise join.
+ */
+ if (ipk1 != ipk2)
+ continue;
+
+ /*
+ * The clause allows partition-wise join if only it uses the same
+ * operator family as that specified by the partition key.
+ */
+ if (!list_member_oid(rinfo->mergeopfamilies,
+ part_scheme->partopfamily[ipk1]))
+ continue;
+
+ /* Mark the partition key as having an equi-join clause. */
+ pk_has_clause[ipk1] = true;
+ }
+
+ /* Check whether every partition key has an equi-join condition. */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * Find the partition key from the given relation matching the given
+ * expression. If found, return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks;
+
+ /* This function should be called only for partitioned relations. */
+ Assert(rel->part_scheme);
+
+ num_pks = rel->part_scheme->partnatts;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() simplifies multiple
+ * RelabelType nodes into one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/path/pathkeys.c b/src/backend/optimizer/path/pathkeys.c
index 4436ac1..6996590 100644
--- a/src/backend/optimizer/path/pathkeys.c
+++ b/src/backend/optimizer/path/pathkeys.c
@@ -1088,12 +1088,24 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
int necs;
ListCell *lc;
int j;
+ Relids relids;
/* Might have no mergeclauses */
if (nClauses == 0)
return NIL;
/*
+ * For a child join relation, use parent relids to find potential
+ * join partners from equivalence classes. A potential join partner of
+ * parent also indicates potential join partner of the child. By using
+ * parent relids we eliminate duplicates arising out of many children.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
+ /*
* Make arrays of the ECs used by the mergeclauses (dropping any
* duplicates) and their "popularity" scores.
*/
@@ -1133,7 +1145,7 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
/* Potential future join partner? */
if (!em->em_is_const && !em->em_is_child &&
- !bms_overlap(em->em_relids, joinrel->relids))
+ !bms_overlap(em->em_relids, relids))
score++;
}
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 32f4031..d7397b3 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -31,6 +31,7 @@
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/paths.h"
+#include "optimizer/pathnode.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
#include "optimizer/planmain.h"
@@ -43,6 +44,7 @@
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
/*
@@ -146,6 +148,9 @@ static CustomScan *create_customscan_plan(PlannerInfo *root,
static NestLoop *create_nestloop_plan(PlannerInfo *root, NestPath *best_path);
static MergeJoin *create_mergejoin_plan(PlannerInfo *root, MergePath *best_path);
static HashJoin *create_hashjoin_plan(PlannerInfo *root, HashPath *best_path);
+static Plan *create_partition_plan(PlannerInfo *root, Path *best_path);
+static Plan *create_partition_join_plan(PlannerInfo *root,
+ PartitionJoinPath *best_path);
static Node *replace_nestloop_params(PlannerInfo *root, Node *expr);
static Node *replace_nestloop_params_mutator(Node *node, PlannerInfo *root);
static void process_subquery_nestloop_params(PlannerInfo *root,
@@ -242,7 +247,8 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
@@ -368,12 +374,8 @@ create_plan_recurse(PlannerInfo *root, Path *best_path, int flags)
(JoinPath *) best_path);
break;
case T_Append:
- plan = create_append_plan(root,
- (AppendPath *) best_path);
- break;
case T_MergeAppend:
- plan = create_merge_append_plan(root,
- (MergeAppendPath *) best_path);
+ plan = create_partition_plan(root, best_path);
break;
case T_Result:
if (IsA(best_path, ProjectionPath))
@@ -1514,7 +1516,7 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
@@ -3524,6 +3526,8 @@ create_mergejoin_plan(PlannerInfo *root,
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
@@ -3531,10 +3535,10 @@ create_mergejoin_plan(PlannerInfo *root,
* best to request a small tlist so we aren't sorting more data than
* necessary.
*/
- outer_plan = create_plan_recurse(root, best_path->jpath.outerjoinpath,
+ outer_plan = create_plan_recurse(root, outer_path,
(best_path->outersortkeys != NIL) ? CP_SMALL_TLIST : 0);
- inner_plan = create_plan_recurse(root, best_path->jpath.innerjoinpath,
+ inner_plan = create_plan_recurse(root, inner_path,
(best_path->innersortkeys != NIL) ? CP_SMALL_TLIST : 0);
/* Sort join qual clauses into best execution order */
@@ -3580,34 +3584,38 @@ create_mergejoin_plan(PlannerInfo *root,
* outer_is_left status.
*/
mergeclauses = get_switched_clauses(best_path->path_mergeclauses,
- best_path->jpath.outerjoinpath->parent->relids);
+ outer_path->parent->relids);
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
outerpathkeys = best_path->outersortkeys;
}
else
- outerpathkeys = best_path->jpath.outerjoinpath->pathkeys;
+ outerpathkeys = outer_path->pathkeys;
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
innerpathkeys = best_path->innersortkeys;
}
else
- innerpathkeys = best_path->jpath.innerjoinpath->pathkeys;
+ innerpathkeys = inner_path->pathkeys;
/*
* If specified, add a materialize node to shield the inner plan from the
@@ -3945,6 +3953,226 @@ create_hashjoin_plan(PlannerInfo *root,
return join_plan;
}
+static Plan *
+create_partition_plan(PlannerInfo *root, Path *best_path)
+{
+ Plan *plan;
+
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root, (PartitionJoinPath *)best_path);
+ else if (best_path->pathtype == T_Append)
+ plan = create_append_plan(root, (AppendPath *) best_path);
+ else
+ {
+ Assert(best_path->pathtype == T_MergeAppend);
+ plan = create_merge_append_plan(root, (MergeAppendPath *) best_path);
+ }
+
+ return plan;
+}
+
+static Plan *
+create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
+{
+ RelOptInfo *joinrel = best_path->path.parent;
+ int nparts;
+ int cnt_parts;
+ List *child_plans = NIL;
+ List *tlist = build_path_tlist(root, &best_path->path);
+ Plan *plan;
+ MemoryContext child_context;
+ MemoryContext old_context;
+ List *pathkeys = best_path->path.pathkeys;
+ StringInfoData mem_context_name;
+
+ /* The relation should be a partitioned join relation. */
+ Assert(IS_JOIN_REL(joinrel) && joinrel->part_scheme &&
+ joinrel->partitioned_joins);
+
+ nparts = joinrel->part_scheme->nparts;
+
+ /* Create MergeAppend plan when result is expected to be ordered. */
+ if (pathkeys)
+ {
+ MergeAppend *node = makeNode(MergeAppend);
+ plan = &node->plan;
+
+ plan->targetlist = tlist;
+
+ /* Compute sorting info, and adjust MergeAppend's tlist as needed. */
+ (void) prepare_sort_from_pathkeys(plan, pathkeys,
+ best_path->path.parent->relids,
+ NULL,
+ true,
+ &node->numCols,
+ &node->sortColIdx,
+ &node->sortOperators,
+ &node->collations,
+ &node->nullsFirst);
+ }
+ else
+ {
+ Append *node = makeNode(Append);
+ plan = &node->plan;
+ plan->targetlist = tlist;
+ }
+
+ /* Fill costs, so that we can cost Sort node, if required. */
+ copy_generic_path_info(plan, (Path *) best_path);
+
+ /*
+ * Create a new memory context for planning child joins. Since this routine
+ * may be called recursively for tables with subpartitions, we use
+ * a unique context name for every level of partition by using the lowest
+ * relid amongst the base relations being joined.
+ */
+ initStringInfo(&mem_context_name);
+ appendStringInfo(&mem_context_name, "%s_%d", "ChildJoinContext",
+ bms_next_member(joinrel->relids, -1));
+ child_context = AllocSetContextCreate(CurrentMemoryContext,
+ pstrdup(mem_context_name.data),
+ ALLOCSET_DEFAULT_SIZES);
+ pfree(mem_context_name.data);
+ resetStringInfo(&mem_context_name);
+
+ /*
+ * Create a paths for all child joins, one child join at a time. The paths
+ * for every child join are independent i.e. one child does not require
+ * paths created for the other. In order to avoid accumulating memory
+ * consumed while creating paths for every child join, we use a fresh
+ * memory context for every child join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_join;
+ Path *child_path;
+ Plan *child_plan;
+ int numsortkeys;
+ AttrNumber *sortColIdx;
+ Oid *sortOperators;
+ Oid *collations;
+ bool *nullsFirst;
+
+ /* Switch to the child_join context to plan for the child join */
+ old_context = MemoryContextSwitchTo(child_context);
+
+ add_paths_to_child_joinrel(root, joinrel, cnt_parts);
+ child_join = joinrel->part_rels[cnt_parts];
+
+ /* Skip empty child. */
+ if (IS_DUMMY_REL(child_join))
+ {
+ MemoryContextSwitchTo(old_context);
+ MemoryContextResetAndDeleteChildren(child_context);
+
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ /*
+ * Search for a child path with pathkeys or parameterization
+ * matching that of the given path.
+ */
+ child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
+ best_path->path.pathkeys,
+ PATH_REQ_OUTER(&best_path->path),
+ TOTAL_COST);
+
+ if (!child_path)
+ elog(ERROR, "Could not find a path with required pathkeys.");
+
+ /* Create plan for the current child. */
+ child_plan = create_plan_recurse(root, child_path, CP_EXACT_TLIST);
+
+ if (pathkeys)
+ {
+ MergeAppend *node = (MergeAppend *) plan;
+
+ Assert(IsA(node, MergeAppend));
+
+ /* Compute sorting info, and adjust subplan's tlist as needed */
+ child_plan = prepare_sort_from_pathkeys(child_plan, pathkeys,
+ child_path->parent->relids,
+ node->sortColIdx,
+ false,
+ &numsortkeys,
+ &sortColIdx,
+ &sortOperators,
+ &collations,
+ &nullsFirst);
+
+ /*
+ * Check that we got the same sort key information. We just Assert
+ * that the sortops match, since those depend only on the pathkeys;
+ * but it seems like a good idea to check the sort column numbers
+ * explicitly, to ensure the tlists really do match up.
+ */
+ Assert(numsortkeys == node->numCols);
+ if (memcmp(sortColIdx, node->sortColIdx,
+ numsortkeys * sizeof(AttrNumber)) != 0)
+ elog(ERROR, "MergeAppend child's targetlist doesn't match MergeAppend");
+ Assert(memcmp(sortOperators, node->sortOperators,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(collations, node->collations,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(nullsFirst, node->nullsFirst,
+ numsortkeys * sizeof(bool)) == 0);
+
+ /* Now, insert a Sort node if subplan isn't sufficiently ordered */
+ if (!pathkeys_contained_in(pathkeys, child_path->pathkeys))
+ {
+ Sort *sort = make_sort(child_plan, numsortkeys,
+ sortColIdx, sortOperators,
+ collations, nullsFirst);
+ label_sort_with_costsize(root, sort, -1.0);
+ child_plan = (Plan *) sort;
+ }
+ }
+
+ /*
+ * Switch to the original context so that we can copy the plan in the
+ * same context as rest of the plan tree.
+ */
+ MemoryContextSwitchTo(old_context);
+ child_plan = copyObject(child_plan);
+
+ child_plans = lappend(child_plans, child_plan);
+
+ /* Reset the child_join memory context to reclaim the memory. */
+ MemoryContextResetAndDeleteChildren(child_context);
+ }
+
+ /* Destroy the child context as we do not need it anymore. */
+ Assert(CurrentMemoryContext == old_context);
+ MemoryContextDelete(child_context);
+
+ /* Partitioned relation with all empty children gets a dummy path. */
+ Assert(child_plans != NIL);
+
+ if (IsA(plan, MergeAppend))
+ {
+ MergeAppend *node = (MergeAppend *)plan;
+
+ node->mergeplans = child_plans;
+ }
+ else
+ {
+ Append *node = (Append *)plan;
+
+ Assert(IsA(plan, Append));
+ node->appendplans = child_plans;
+ }
+
+ /* Complete rest of the plan. */
+ plan->qual = NIL;
+ plan->lefttree = NULL;
+ plan->righttree = NULL;
+ return plan;
+}
+
/*****************************************************************************
*
@@ -3971,6 +4199,8 @@ replace_nestloop_params(PlannerInfo *root, Node *expr)
static Node *
replace_nestloop_params_mutator(Node *node, PlannerInfo *root)
{
+ MemoryContext old_context;
+
if (node == NULL)
return NULL;
if (IsA(node, Var))
@@ -3999,10 +4229,13 @@ replace_nestloop_params_mutator(Node *node, PlannerInfo *root)
}
}
/* No, so add it */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
nlp = makeNode(NestLoopParam);
nlp->paramno = param->paramid;
nlp->paramval = var;
root->curOuterParams = lappend(root->curOuterParams, nlp);
+ MemoryContextSwitchTo(old_context);
+
/* And return the replacement Param */
return (Node *) param;
}
@@ -4062,10 +4295,13 @@ replace_nestloop_params_mutator(Node *node, PlannerInfo *root)
}
}
/* No, so add it */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
nlp = makeNode(NestLoopParam);
nlp->paramno = param->paramid;
nlp->paramval = (Var *) phv;
root->curOuterParams = lappend(root->curOuterParams, nlp);
+ MemoryContextSwitchTo(old_context);
+
/* And return the replacement Param */
return (Node *) param;
}
@@ -5337,11 +5573,11 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
@@ -5452,10 +5688,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
@@ -5476,9 +5712,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
@@ -5488,7 +5725,7 @@ make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index f657ffc..3c0898a 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -1108,7 +1108,7 @@ inheritance_planner(PlannerInfo *root)
subroot->parse = (Query *)
adjust_appendrel_attrs(root,
(Node *) parse,
- appinfo);
+ list_make1(appinfo));
/*
* The rowMarks list might contain references to subquery RTEs, so
diff --git a/src/backend/optimizer/plan/subselect.c b/src/backend/optimizer/plan/subselect.c
index 263ba45..6f3270a 100644
--- a/src/backend/optimizer/plan/subselect.c
+++ b/src/backend/optimizer/plan/subselect.c
@@ -96,6 +96,7 @@ assign_param_for_var(PlannerInfo *root, Var *var)
ListCell *ppl;
PlannerParamItem *pitem;
Index levelsup;
+ MemoryContext old_context;
/* Find the query level the Var belongs to */
for (levelsup = var->varlevelsup; levelsup > 0; levelsup--)
@@ -124,7 +125,9 @@ assign_param_for_var(PlannerInfo *root, Var *var)
}
}
- /* Nope, so make a new one */
+
+ /* Nope, so make a new one in the planner context */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
var = (Var *) copyObject(var);
var->varlevelsup = 0;
@@ -134,6 +137,8 @@ assign_param_for_var(PlannerInfo *root, Var *var)
root->plan_params = lappend(root->plan_params, pitem);
+ MemoryContextSwitchTo(old_context);
+
return pitem->paramId;
}
@@ -204,6 +209,7 @@ assign_param_for_placeholdervar(PlannerInfo *root, PlaceHolderVar *phv)
ListCell *ppl;
PlannerParamItem *pitem;
Index levelsup;
+ MemoryContext old_context;
/* Find the query level the PHV belongs to */
for (levelsup = phv->phlevelsup; levelsup > 0; levelsup--)
@@ -223,7 +229,8 @@ assign_param_for_placeholdervar(PlannerInfo *root, PlaceHolderVar *phv)
}
}
- /* Nope, so make a new one */
+ /* Nope, so make a new one in the planner's context. */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
phv = (PlaceHolderVar *) copyObject(phv);
if (phv->phlevelsup != 0)
{
@@ -237,6 +244,8 @@ assign_param_for_placeholdervar(PlannerInfo *root, PlaceHolderVar *phv)
root->plan_params = lappend(root->plan_params, pitem);
+ MemoryContextSwitchTo(old_context);
+
return pitem->paramId;
}
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 193b2c9..1ce142e 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -55,7 +55,7 @@
typedef struct
{
PlannerInfo *root;
- AppendRelInfo *appinfo;
+ List *appinfos;
int sublevels_up;
} adjust_appendrel_attrs_context;
@@ -108,7 +108,6 @@ static Bitmapset *translate_col_privs(const Bitmapset *parent_privs,
List *translated_vars);
static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
-static Relids adjust_relid_set(Relids relids, Index oldrelid, Index newrelid);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
static List *expand_inherited_rte_internal(PlannerInfo *root, RangeTblEntry *rte,
@@ -1828,10 +1827,11 @@ translate_col_privs(const Bitmapset *parent_privs,
/*
* adjust_appendrel_attrs
- * Copy the specified query or expression and translate Vars referring
- * to the parent rel of the specified AppendRelInfo to refer to the
- * child rel instead. We also update rtindexes appearing outside Vars,
- * such as resultRelation and jointree relids.
+ *
+ * Copy the specified query or expression and translate Vars referring to
+ * the parent rels specified in the given list of AppendRelInfos to refer to
+ * the corresponding child rels instead. We also update rtindexes appearing
+ * outside Vars, such as resultRelation and jointree relids.
*
* Note: this is applied after conversion of sublinks to subplans in the
* query jointree, but there may still be sublinks in the security barrier
@@ -1841,15 +1841,18 @@ translate_col_privs(const Bitmapset *parent_privs,
* maybe we should try to fold the two routines together.
*/
Node *
-adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
+adjust_appendrel_attrs(PlannerInfo *root, Node *node, List *appinfos)
{
Node *result;
adjust_appendrel_attrs_context context;
+ ListCell *lc;
context.root = root;
- context.appinfo = appinfo;
+ context.appinfos = appinfos;
context.sublevels_up = 0;
+ Assert(appinfos && list_length(appinfos) >= 1);
+
/*
* Must be prepared to start with a Query or a bare expression tree; if
* it's a Query, go straight to query_tree_walker to make sure that
@@ -1858,11 +1861,20 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
if (node && IsA(node, Query))
{
Query *newnode;
+ AppendRelInfo *appinfo;
newnode = query_tree_mutator((Query *) node,
adjust_appendrel_attrs_mutator,
(void *) &context,
QTW_IGNORE_RC_SUBQUERIES);
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (newnode->resultRelation == appinfo->parent_relid)
+ break;
+ }
+
if (newnode->resultRelation == appinfo->parent_relid)
{
newnode->resultRelation = appinfo->child_relid;
@@ -1880,17 +1892,73 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
return result;
}
+/*
+ * find_appinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *appinfo_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (bms_is_member(appinfo->child_relid, relids))
+ appinfo_list = lappend(appinfo_list, appinfo);
+ }
+
+ Assert(list_length(appinfo_list) == bms_num_members(relids));
+ return appinfo_list;
+}
+
+/*
+ * adjust_join_appendrel_attrs
+ *
+ * Replace the parent references in the given node by the child references
+ * specified by the list of AppendRelInfo.
+ *
+ * This function is a wrapper around adjust_appendrel_attrs() which handles
+ * only one AppendRelInfo at a time.
+ */
+
+Node *
+adjust_join_appendrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos)
+{
+ return adjust_appendrel_attrs(root, node, append_rel_infos);
+}
+
static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
- AppendRelInfo *appinfo = context->appinfo;
+ List *appinfos = context->appinfos;
+ ListCell *lc;
+
+ Assert(appinfos && list_length(appinfos) >= 1);
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
Var *var = (Var *) copyObject(node);
+ AppendRelInfo *appinfo;
+
+ /*
+ * Find an appinfo, parent in which matches the Var. If none found, set
+ * it to the last one. Rest of the code takes care of non-matching
+ * appinfos.
+ */
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (var->varno == appinfo->parent_relid)
+ break;
+ }
if (var->varlevelsup == context->sublevels_up &&
var->varno == appinfo->parent_relid)
@@ -1981,32 +2049,58 @@ adjust_appendrel_attrs_mutator(Node *node,
{
CurrentOfExpr *cexpr = (CurrentOfExpr *) copyObject(node);
- if (context->sublevels_up == 0 &&
- cexpr->cvarno == appinfo->parent_relid)
- cexpr->cvarno = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ cexpr->cvarno == appinfo->parent_relid)
+ {
+ cexpr->cvarno = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) cexpr;
}
if (IsA(node, RangeTblRef))
{
RangeTblRef *rtr = (RangeTblRef *) copyObject(node);
- if (context->sublevels_up == 0 &&
- rtr->rtindex == appinfo->parent_relid)
- rtr->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ rtr->rtindex == appinfo->parent_relid)
+ {
+ rtr->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) rtr;
}
if (IsA(node, JoinExpr))
{
/* Copy the JoinExpr node with correct mutation of subnodes */
JoinExpr *j;
+ AppendRelInfo *appinfo;
j = (JoinExpr *) expression_tree_mutator(node,
adjust_appendrel_attrs_mutator,
(void *) context);
+
/* now fix JoinExpr's rtindex (probably never happens) */
- if (context->sublevels_up == 0 &&
- j->rtindex == appinfo->parent_relid)
- j->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ j->rtindex == appinfo->parent_relid)
+ {
+ j->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) j;
}
if (IsA(node, PlaceHolderVar))
@@ -2019,9 +2113,8 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == context->sublevels_up)
- phv->phrels = adjust_relid_set(phv->phrels,
- appinfo->parent_relid,
- appinfo->child_relid);
+ phv->phrels = adjust_child_relids(bms_copy(phv->phrels),
+ context->appinfos);
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -2052,24 +2145,18 @@ adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_mutator((Node *) oldinfo->orclause, context);
/* adjust relid sets too */
- newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ newinfo->clause_relids = adjust_child_relids(bms_copy(oldinfo->clause_relids),
+ context->appinfos);
+ newinfo->required_relids = adjust_child_relids(bms_copy(oldinfo->required_relids),
+ context->appinfos);
+ newinfo->outer_relids = adjust_child_relids(bms_copy(oldinfo->outer_relids),
+ context->appinfos);
+ newinfo->nullable_relids = adjust_child_relids(bms_copy(oldinfo->nullable_relids),
+ context->appinfos);
+ newinfo->left_relids = adjust_child_relids(bms_copy(oldinfo->left_relids),
+ context->appinfos);
+ newinfo->right_relids = adjust_child_relids(bms_copy(oldinfo->right_relids),
+ context->appinfos);
/*
* Reset cached derivative fields, since these might need to have
@@ -2118,23 +2205,6 @@ adjust_appendrel_attrs_mutator(Node *node,
}
/*
- * Substitute newrelid for oldrelid in a Relid set
- */
-static Relids
-adjust_relid_set(Relids relids, Index oldrelid, Index newrelid)
-{
- if (bms_is_member(oldrelid, relids))
- {
- /* Ensure we have a modifiable copy */
- relids = bms_copy(relids);
- /* Remove old, add new */
- relids = bms_del_member(relids, oldrelid);
- relids = bms_add_member(relids, newrelid);
- }
- return relids;
-}
-
-/*
* Adjust the targetlist entries of an inherited UPDATE operation
*
* The expressions have already been fixed, but we have to make sure that
@@ -2251,5 +2321,5 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
else
Assert(parent_rel->reloptkind == RELOPT_BASEREL);
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, appinfo);
+ return adjust_appendrel_attrs(root, node, list_make1(appinfo));
}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index abb7507..8510775 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -23,7 +23,9 @@
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
@@ -2154,6 +2156,162 @@ create_hashjoin_path(PlannerInfo *root,
}
/*
+ * create_partition_join_path
+ * Creates a pathnode that represents partition-wise join for given
+ * partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the costs of the list of paths for
+ * representative child-joins.
+ */
+PartitionJoinPath *
+create_partition_join_path(RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = T_Append;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = NULL;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+ subpath_total_cost += subpath->total_cost;
+
+ /*
+ * Startup cost of an append relation is the startup cost of the first
+ * subpath. Assume that the given first child will be the first child
+ * in the final plan as well.
+ */
+ if (lc == list_head(subpaths))
+ subpath_startup_cost = subpath->startup_cost;
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ pathnode->path.startup_cost = subpath_startup_cost;
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ return pathnode;
+}
+
+/*
+ * create_partition_join_path_with_pathkeys
+ * Creates a pathnode that represents an ordered partition-wise join for
+ * given partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the costs of the list of paths for
+ * representative child-joins.
+ */
+PartitionJoinPath *
+create_partition_join_path_with_pathkeys(PlannerInfo *root, RelOptInfo *rel,
+ List *subpaths, List *pathkeys,
+ Bitmapset *required_outer)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = T_MergeAppend;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = pathkeys;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ if (pathkeys_contained_in(pathkeys, subpath->pathkeys))
+ {
+ /* Subpath is adequately ordered, we won't need to sort it */
+ subpath_startup_cost += subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else
+ {
+ /* We'll need to insert a Sort node, so include cost for that */
+ Path sort_path; /* dummy for result of cost_sort */
+
+ cost_sort(&sort_path,
+ root,
+ pathkeys,
+ subpath->total_cost,
+ subpath->parent->tuples,
+ subpath->pathtarget->width,
+ 0.0,
+ work_mem,
+ -1);
+ subpath_startup_cost += sort_path.startup_cost;
+ subpath_total_cost += sort_path.total_cost;
+ }
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ pathnode->path.startup_cost = (subpath_startup_cost * pathnode->path.rows) / subpath_rows;
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ return pathnode;
+}
+/*
* create_projection_path
* Creates a pathnode that represents performing a projection.
*
@@ -3209,3 +3367,158 @@ reparameterize_path(PlannerInfo *root, Path *path,
}
return NULL;
}
+
+/*
+ * reparameterize_path_by_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ *
+ * The cost, number of rows, width and parallel path properties depend upon
+ * path->parent, which does not change during the translation. Hence those
+ * members are copied as they are.
+ */
+
+Path *
+reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+
+ /*
+ * If the path is not parameterized by parent of the given relation, it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = adjust_child_relids(bms_copy(old_ppi->ppi_req_outer),
+ child_aris);
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) old_ppi->ppi_clauses,
+ child_aris);
+
+ /* Adjust the path target. */
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ new_path->param_info = new_ppi;
+
+ /*
+ * Change parameterization of subpaths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_by_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_by_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_by_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexquals = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) ipath->indexquals,
+ child_aris);
+ ipath->indexquals = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) ipath->indexorderbys,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/placeholder.c b/src/backend/optimizer/util/placeholder.c
index b210914..98e95e0 100644
--- a/src/backend/optimizer/util/placeholder.c
+++ b/src/backend/optimizer/util/placeholder.c
@@ -21,6 +21,7 @@
#include "optimizer/placeholder.h"
#include "optimizer/planmain.h"
#include "optimizer/var.h"
+#include "optimizer/prep.h"
#include "utils/lsyscache.h"
/* Local functions */
@@ -411,9 +412,15 @@ void
add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *lc;
+ /* PlaceHolderInfo refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(lc, root->placeholder_list)
{
PlaceHolderInfo *phinfo = (PlaceHolderInfo *) lfirst(lc);
@@ -424,9 +431,27 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
/* Is it computable here? */
if (bms_is_subset(phinfo->ph_eval_at, relids))
{
+ PlaceHolderVar *phv = phinfo->ph_var;
+
+ /*
+ * In case the placeholder Var refers to any of the parent
+ * relation, translate it to refer to the corresponding child.
+ */
+ if (bms_overlap(phv->phrels, relids) &&
+ joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ {
+ List *append_rel_infos;
+
+ append_rel_infos = find_appinfos_by_relids(root,
+ joinrel->relids);
+ phv = (PlaceHolderVar *) adjust_join_appendrel_attrs(root,
+ (Node *) phv,
+ append_rel_infos);
+ }
+
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs,
- phinfo->ph_var);
+ phv);
joinrel->reltarget->width += phinfo->ph_width;
/*
@@ -445,7 +470,7 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
{
QualCost cost;
- cost_qual_eval_node(&cost, (Node *) phinfo->ph_var->phexpr,
+ cost_qual_eval_node(&cost, (Node *) phv->phexpr,
root);
joinrel->reltarget->cost.startup += cost.startup;
joinrel->reltarget->cost.per_tuple += cost.per_tuple;
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index f8bfa4b..a0e17d5 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -411,6 +411,21 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation);
+ /*
+ * Lookup partition scheme for the given relation. Only parent relations
+ * can be partitioned.
+ */
+ if (inhparent)
+ rel->part_scheme = find_partition_scheme(root, relation);
+ else
+ rel->part_scheme = NULL;
+
+ if (rel->part_scheme)
+ rel->partexprs = build_baserel_partition_key_exprs(relation,
+ rel->relid);
+ else
+ rel->partexprs = NULL;
+
heap_close(relation, NoLock);
/*
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index deef560..be08b6e 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -15,15 +15,22 @@
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
+#include "catalog/partition.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
+#include "nodes/makefuncs.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "optimizer/var.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
@@ -47,6 +54,11 @@ static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
/*
@@ -137,6 +149,10 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
rel->baserestrictcost.per_tuple = 0;
rel->joininfo = NIL;
rel->has_eclass_joins = false;
+ rel->part_scheme = NULL;
+ rel->partexprs = NULL;
+ rel->top_parent_relids = NULL;
+ rel->part_rels = NULL;
/* Check type of rtable entry */
switch (rte->rtekind)
@@ -314,6 +330,56 @@ find_join_rel(PlannerInfo *root, Relids relids)
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
@@ -363,7 +429,11 @@ build_join_rel(PlannerInfo *root,
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
+
+ Assert(!IS_OTHER_REL(outer_rel->reloptkind) &&
+ !IS_OTHER_REL(inner_rel->reloptkind));
joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
@@ -409,47 +479,13 @@ build_join_rel(PlannerInfo *root,
joinrel->baserestrictcost.per_tuple = 0;
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Compute information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
@@ -475,6 +511,10 @@ build_join_rel(PlannerInfo *root,
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
@@ -517,25 +557,8 @@ build_join_rel(PlannerInfo *root,
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the query's PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
@@ -555,6 +578,132 @@ build_join_rel(PlannerInfo *root,
}
/*
+ * build_child_join_rel
+ * Builds RelOptInfo for joining given two child relations from RelOptInfo
+ * representing the join between their parents.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of child relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for child join
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_appinfos': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ JoinType jointype)
+{
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+ List *join_appinfos;
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel->reloptkind) &&
+ IS_OTHER_REL(inner_rel->reloptkind));
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Compute information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /* Build targetlist */
+ build_joinrel_tlist(root, joinrel, outer_rel);
+ build_joinrel_tlist(root, joinrel, inner_rel);
+ /* Add placeholder variables. */
+ add_placeholders_to_joinrel(root, joinrel, outer_rel, inner_rel);
+
+ /* Translate joininfo. */
+ join_appinfos = find_appinfos_by_relids(root, joinrel->relids);
+ joinrel->joininfo = (List *) adjust_join_appendrel_attrs(root,
+ (Node *) parent_joinrel->joininfo,
+ join_appinfos);
+
+ /*
+ * Lateral relids referred in child join will be same as that referred in
+ * the parent relation. Throw any partial result computed while building
+ * the targetlist.
+ */
+ bms_free(joinrel->direct_lateral_relids);
+ bms_free(joinrel->lateral_relids);
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, jointype);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ /* We build the join only once. */
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ pfree(join_appinfos);
+
+ return joinrel;
+}
+
+/*
* min_join_parameterization
*
* Determine the minimum possible parameterization of a joinrel, that is, the
@@ -609,9 +758,15 @@ static void
build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *vars;
+ /* attrs_needed refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(vars, input_rel->reltarget->exprs)
{
Var *var = (Var *) lfirst(vars);
@@ -627,23 +782,47 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
/*
* Otherwise, anything in a baserel or joinrel targetlist ought to be
- * a Var. (More general cases can only appear in appendrel child
- * rels, which will never be seen here.)
+ * a Var or ConvertRowtypeExpr introduced while translating parent
+ * targetlist to that of the child.
*/
- if (!IsA(var, Var))
+ if (IsA(var, Var))
+ {
+ /* Get the Var's original base rel */
+ baserel = find_base_rel(root, var->varno);
+
+ /* Is it still needed above this joinrel? */
+ ndx = var->varattno - baserel->min_attr;
+ }
+ else if (IsA(var, ConvertRowtypeExpr))
+ {
+ ConvertRowtypeExpr *child_expr = (ConvertRowtypeExpr *) var;
+ Var *childvar = (Var *) child_expr->arg;
+
+ /*
+ * Child's whole-row references are converted to that of parent
+ * using ConvertRowtypeExpr. In this case, the argument to
+ * ConvertRowtypeExpr is expected to be a whole-row reference of
+ * the child.
+ */
+ Assert(IsA(childvar, Var) && childvar->varattno == 0);
+
+ baserel = find_base_rel(root, childvar->varno);
+ ndx = 0 - baserel->min_attr;
+ }
+ else
elog(ERROR, "unexpected node type in rel targetlist: %d",
(int) nodeTag(var));
- /* Get the Var's original base rel */
- baserel = find_base_rel(root, var->varno);
-
- /* Is it still needed above this joinrel? */
- ndx = var->varattno - baserel->min_attr;
if (bms_nonempty_difference(baserel->attr_needed[ndx], relids))
{
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs, var);
- /* Vars have cost zero, so no need to adjust reltarget->cost */
+
+ /*
+ * Vars have cost zero, so no need to adjust reltarget->cost. Even
+ * if, it's a ConvertRowtypeExpr, it will be computed only for the
+ * base relation, costing nothing for a join.
+ */
joinrel->reltarget->width += baserel->attr_widths[ndx];
}
}
@@ -1320,3 +1499,111 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
return ppi;
}
+
+/*
+ * add_join_rel
+ * Add given join relation to the list of join relations in the given
+ * PlannerInfo. Also add it to the auxiliary hashtable if there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
+ * build_joinrel_partition_info
+ * If the join between given partitioned relations is possibly partitioned
+ * set the partitioning scheme and partition keys expressions for the
+ * join.
+ *
+ * If the two relations have same partitioning scheme, their join may be
+ * partitioned and will follow the same partitioning scheme as the joining
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /* Nothing to do if partition-wise join technique is disabled. */
+ if (!enable_partition_wise_join)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * The join is not partitioned, if any of the relations being joined are
+ * not partitioned or they do not have same partitioning scheme.
+ */
+ if (!outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel, hence it should
+ * not have partition scheme, partition key expressions and array for
+ * storing child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ /*
+ * Join relation is partitioned using same partitioning scheme as the
+ * joining relations.
+ */
+ joinrel->part_scheme = outer_rel->part_scheme;
+ num_pks = joinrel->part_scheme->partnatts;
+
+ /*
+ * Construct partition keys for the join.
+ *
+ * An INNER join between two partitioned relations is partition by key
+ * expressions from both the relations. For tables A and B partitioned by a and b
+ * respectively, (A INNER JOIN B ON A.a = B.b) is partitioned by both A.a
+ * and B.b.
+ *
+ * An OUTER join like (A LEFT JOIN B ON A.a = B.b) may produce rows with
+ * B.b NULL. These rows may not fit the partitioning conditions imposed on
+ * B.b. Hence, strictly speaking, the join is not partitioned by B.b.
+ * Strictly speaking, partition keys of an OUTER join should include
+ * partition key expressions from the OUTER side only. Consider a join like
+ * (A LEFT JOIN B on (A.a = B.b) LEFT JOIN C ON B.b = C.c. If we do not
+ * include B.b as partition key expression for (AB), it prohibits us from
+ * using partition-wise join when joining (AB) with C as there is no
+ * equi-join between partition keys of joining relations. But two NULL
+ * values are never equal and no two rows from mis-matching partitions can
+ * join. Hence it's safe to include B.b as partition key expression for
+ * (AB), even though rows in (AB) are not strictly partitioned by B.b.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
diff --git a/src/backend/postmaster/startup.c b/src/backend/postmaster/startup.c
index a7ae7e3..6787df6 100644
--- a/src/backend/postmaster/startup.c
+++ b/src/backend/postmaster/startup.c
@@ -169,7 +169,6 @@ HandleStartupProcInterrupts(void)
exit(1);
}
-
/* ----------------------------------
* Startup Process main entry point
* ----------------------------------
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 56943f2..16b2eac 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3412,7 +3412,9 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
if (rel->tuples > 0)
{
/*
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index ce4eef9..edc7e58 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -877,6 +877,15 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
diff --git a/src/include/catalog/partition.h b/src/include/catalog/partition.h
index 81a4b91..19b7744 100644
--- a/src/include/catalog/partition.h
+++ b/src/include/catalog/partition.h
@@ -46,8 +46,43 @@ typedef struct PartitionDescData
BoundCollection bounds; /* collection of list or range bounds */
} PartitionDescData;
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting may be partitioned in the same way as the underlying
+ * scan relations. All such relations partitioned in the same way share the
+ * partitioning scheme.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ BoundCollection bounds; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
typedef struct PartitionDescData *PartitionDesc;
typedef struct PartitionTreeNodeData *PartitionTreeNode;
+typedef struct PartitionSchemeData *PartitionScheme;
+
+/* Include here to avoid circular dependency with relation.h. */
+struct PlannerInfo;
/* relcache support for partition key information */
extern void RelationBuildPartitionKey(Relation relation);
@@ -84,4 +119,9 @@ extern int get_partition_for_tuple(PartitionTreeNode ptnode,
TupleTableSlot *slot,
EState *estate,
Oid *failed_at);
+extern List **build_baserel_partition_key_exprs(Relation relation,
+ Index varno);
+extern PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+
#endif /* PARTITION_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 2f9e7d3..94bce51 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -238,6 +238,7 @@ typedef enum NodeTag
T_NestPath,
T_MergePath,
T_HashPath,
+ T_PartitionJoinPath,
T_AppendPath,
T_MergeAppendPath,
T_ResultPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 3a1255a..18f1e5c 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -15,6 +15,7 @@
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
@@ -263,6 +264,9 @@ typedef struct PlannerInfo
List *initial_rels; /* RelOptInfos we are now trying to join */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
/* Use fetch_upper_rel() to get any particular upper rel */
List *upper_rels[UPPERREL_FINAL + 1]; /* upper-rel RelOptInfos */
@@ -352,6 +356,11 @@ typedef struct PlannerInfo
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing joins between child relations of
+ * different partitioned tables. These relations are not added to
+ * join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
@@ -471,10 +480,19 @@ typedef enum RelOptKind
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(reloptkind) \
+ ((reloptkind) == RELOPT_OTHER_MEMBER_REL || \
+ (reloptkind) == RELOPT_OTHER_JOINREL)
+
+#define IS_JOIN_REL(rel) \
+ ((rel->reloptkind) == RELOPT_JOINREL || \
+ (rel->reloptkind) == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
@@ -542,6 +560,27 @@ typedef struct RelOptInfo
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there may be as many elements
+ * as the number of joining
+ * relations.
+ */
+ List *partitioned_joins; /* List of join orders which yield
+ * relations partitioned by above
+ * partition scheme.
+ */
+
+ /* Set only for "other" base or join relations. */
+ Relids top_parent_relids; /* Relids of topmost parents. */
} RelOptInfo;
/*
@@ -1469,6 +1508,14 @@ typedef struct LimitPath
Node *limitCount; /* COUNT parameter, or NULL if none */
} LimitPath;
+/*
+ * PartitionJoinPath represents partition-wise join between two partitioned
+ * tables.
+ */
+typedef struct PartitionJoinPath
+{
+ Path path;
+} PartitionJoinPath;
/*
* Restriction clause info.
@@ -1785,6 +1832,20 @@ typedef struct SpecialJoinInfo
} SpecialJoinInfo;
/*
+ * Partitioned join information
+ *
+ * Saves information about relations which can be joined partition-wise and
+ * thus produce result partitioned by the partition scheme of the relation.
+ */
+typedef struct PartitionedJoin
+{
+ RelOptInfo *rel1;
+ RelOptInfo *rel2;
+ SpecialJoinInfo *sjinfo;
+ List *restrictlist;
+} PartitionedJoin;
+
+/*
* Append-relation info.
*
* When we expand an inheritable table or a UNION-ALL subselect into an
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..1069726 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -66,6 +66,7 @@ extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
extern double clamp_row_est(double nrows);
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 71d9154..44dc801 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -225,10 +225,17 @@ extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
+extern PartitionJoinPath *create_partition_join_path(RelOptInfo *rel,
+ List *subpaths, Bitmapset *required_outer);
+extern PartitionJoinPath *create_partition_join_path_with_pathkeys(PlannerInfo *root,
+ RelOptInfo *rel, List *subpaths,
+ List *pathkeys, Bitmapset *required_outer);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
@@ -267,5 +274,10 @@ extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, JoinType jointype);
+
+extern void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..5d7bcd9 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -53,6 +53,8 @@ extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
extern void generate_gather_paths(PlannerInfo *root, RelOptInfo *rel);
+extern void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
#ifdef OPTIMIZER_DEBUG
extern void debug_print_rel(PlannerInfo *root, RelOptInfo *rel);
@@ -104,6 +106,9 @@ extern bool have_join_order_restriction(PlannerInfo *root,
RelOptInfo *rel1, RelOptInfo *rel2);
extern bool have_dangerous_phv(PlannerInfo *root,
Relids outer_relids, Relids inner_params);
+extern void add_paths_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *parent_joinrel,
+ int child_id);
/*
* equivclass.c
@@ -219,4 +224,6 @@ extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
+
#endif /* PATHS_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index fb35b68..58df2f4 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -28,6 +28,9 @@ extern void flatten_simple_union_all(PlannerInfo *root);
extern void reduce_outer_joins(PlannerInfo *root);
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
+extern Node *adjust_join_appendrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos);
+extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
/*
* prototypes for prepqual.c
@@ -58,7 +61,7 @@ extern RelOptInfo *plan_set_operations(PlannerInfo *root);
extern void expand_inherited_tables(PlannerInfo *root);
extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
- AppendRelInfo *appinfo);
+ List *appinfos);
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
diff --git a/src/test/regress/expected/multi_level_partition_join.out b/src/test/regress/expected/multi_level_partition_join.out
new file mode 100644
index 0000000..2fcf779
--- /dev/null
+++ b/src/test/regress/expected/multi_level_partition_join.out
@@ -0,0 +1,458 @@
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.b = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text) AND ((t1_1.b + t1_1.a) = (t2_1.a + t2_1.b)))
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.b = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text) AND ((t1_2.b + t1_2.a) = (t2_2.a + t2_2.b)))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
+ Hash Cond: ((t1_3.a = t2_3.b) AND (t1_3.b = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text) AND ((t1_3.b + t1_3.a) = (t2_3.a + t2_3.b)))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Hash
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: ((t2_3.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_4.b, t2_4.c, t1_4.a, t1_4.c
+ Hash Cond: ((t1_4.a = t2_4.b) AND (t1_4.b = t2_4.a) AND ((t1_4.c)::text = (t2_4.c)::text) AND ((t1_4.b + t1_4.a) = (t2_4.a + t2_4.b)))
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Hash
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: ((t2_4.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_5.b, t2_5.c, t1_5.a, t1_5.c
+ Hash Cond: ((t1_5.a = t2_5.b) AND (t1_5.b = t2_5.a) AND ((t1_5.c)::text = (t2_5.c)::text) AND ((t1_5.b + t1_5.a) = (t2_5.a + t2_5.b)))
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Hash
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: ((t2_5.b % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Sort Key: prt1_l_p1_p1.a, prt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt2_l_p1_p2.b, prt2_l_p1_p2.c
+ Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..eb2015c
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,5043 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t2.a, t2.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t2_1.a, t2_1.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t2_2.a, t2_2.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.a = t1_3.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.a = t1_4.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.a = t1_5.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(58 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Index Scan using iprt1_a on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(41 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.c = t1.c) AND (t2.a = t1.a))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.c = t1_1.c) AND (t2_1.a = t1_1.a))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.c = t1_2.c) AND (t2_2.a = t1_2.a))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0003 | 150 | 0003
+ 300 | 0006 | 300 | 0006
+ 450 | 0009 | 450 | 0009
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75 | 0001
+ | | 225 | 0004
+ | | 375 | 0007
+ | | 525 | 0010
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, avg(plt2_p1.b), plt2_p1.c
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, plt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+-----+------+------------------------+------
+ 0 | 0000 | 0.00000000000000000000 | 0000
+ 50 | 0001 | |
+ 100 | 0002 | |
+ 150 | 0003 | 150.0000000000000000 | 0003
+ 200 | 0004 | |
+ 250 | 0005 | |
+ 300 | 0006 | 300.0000000000000000 | 0006
+ 350 | 0007 | |
+ 400 | 0008 | |
+ 450 | 0009 | 450.0000000000000000 | 0009
+ 500 | 0010 | |
+ 550 | 0011 | |
+ | | 75.0000000000000000 | 0001
+ | | 225.0000000000000000 | 0004
+ | | 375.0000000000000000 | 0007
+ | | 525.0000000000000000 | 0010
+(16 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(plt1_p1.a), plt1_p1.c, sum((25)), avg(plt2_p1.b), plt2_p1.c, avg((50))
+ Group Key: plt1_p1.c, plt2_p1.c
+ -> Sort
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ Sort Key: plt1_p1.c, plt2_p1.c
+ -> Result
+ Output: plt1_p1.c, plt2_p1.c, plt1_p1.a, (25), plt2_p1.b, (50)
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (25), (50)
+ Hash Cond: ((plt1_p1.c = plt2_p1.c) AND (plt1_p1.a = plt2_p1.b))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c, 25
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c, (50)
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c, 50
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, (25), (50)
+ Hash Cond: ((plt1_p2.c = plt2_p2.c) AND (plt1_p2.a = plt2_p2.b))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c, 25
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c, (50)
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c, 50
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, (25), (50)
+ Hash Cond: ((plt1_p3.c = plt2_p3.c) AND (plt1_p3.a = plt2_p3.b))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c, 25
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c, (50)
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c, 50
+ Filter: ((plt2_p3.b % 25) = 0)
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | avg | c | avg
+-----+------+-----+------------------------+------+---------------------
+ 0 | 0000 | 25 | 0.00000000000000000000 | 0000 | 50.0000000000000000
+ 50 | 0001 | 25 | | |
+ 100 | 0002 | 25 | | |
+ 150 | 0003 | 25 | 150.0000000000000000 | 0003 | 50.0000000000000000
+ 200 | 0004 | 25 | | |
+ 250 | 0005 | 25 | | |
+ 300 | 0006 | 25 | 300.0000000000000000 | 0006 | 50.0000000000000000
+ 350 | 0007 | 25 | | |
+ 400 | 0008 | 25 | | |
+ 450 | 0009 | 25 | 450.0000000000000000 | 0009 | 50.0000000000000000
+ 500 | 0010 | 25 | | |
+ 550 | 0011 | 25 | | |
+ | | | 75.0000000000000000 | 0001 | 50.0000000000000000
+ | | | 225.0000000000000000 | 0004 | 50.0000000000000000
+ | | | 375.0000000000000000 | 0007 | 50.0000000000000000
+ | | | 525.0000000000000000 | 0010 | 50.0000000000000000
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (avg(t2.b)), t2.c
+ Sort Key: t1.c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, avg(t2.b), t2.c
+ Group Key: t1.c, t2.c
+ -> Result
+ Output: t1.c, t2.c, t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(20 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | avg | c
+--------+------+----------------------+------
+ 137700 | 0006 | 324.0000000000000000 | 0006
+ 158950 | 0007 | 375.0000000000000000 | 0007
+ 169600 | 0008 | 424.5000000000000000 | 0008
+ 229600 | 0011 | 574.5000000000000000 | 0011
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Left Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Left Join
+ Output: t1_1.a, t1_1.c, t2.b, t2.c
+ Hash Cond: (t1_1.c = t2.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.plt2_p3 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(a)), c, (sum(t2.b)), t2.c
+ Sort Key: c, t2.c
+ -> HashAggregate
+ Output: sum(a), c, sum(t2.b), t2.c
+ Group Key: c, t2.c
+ -> Result
+ Output: c, t2.c, a, t2.b
+ -> Append
+ -> Hash Left Join
+ Output: t2.b, t2.c, a, c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1.a, t1.c
+ Hash Cond: (t1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(31 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(t1.a)), t1.c, (sum(b)), c
+ Sort Key: t1.c, c
+ -> HashAggregate
+ Output: sum(t1.a), t1.c, sum(b), c
+ Group Key: t1.c, c
+ -> Result
+ Output: t1.c, c, t1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: t1.a, t1.c, b, c
+ Hash Cond: (t1.c = c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: (t1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.c = c)
+ -> Seq Scan on public.plt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: (t1_1.c <> ALL ('{0001,0005,0002,0009}'::text[]))
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.plt2_p3 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: (t2_1.c <> ALL ('{0000,0003,0004,0010}'::text[]))
+(42 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+ sum | c | sum | c
+--------+------+--------+------
+ 600 | 0000 | |
+ 4350 | 0003 | |
+ 5600 | 0004 | |
+ 137700 | 0006 | 137700 | 0006
+ 158950 | 0007 | 159375 | 0007
+ 169600 | 0008 | 169800 | 0008
+ 13100 | 0010 | |
+ 229600 | 0011 | 229800 | 0011
+ | | 1275 | 0001
+ | | 1992 | 0002
+ | | 4392 | 0005
+ | | 8058 | 0009
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.c
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ Filter: ((t1_3.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.c
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ Filter: ((t1_4.b % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.c
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ Filter: ((t1_5.b % 25) = 0)
+(37 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+(8 rows)
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (ltrim(t2.c, 'A'::text) = ltrim(t1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_e_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (ltrim(t2_1.c, 'A'::text) = ltrim(t1_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (ltrim(t2_2.c, 'A'::text) = ltrim(t1_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Sort Key: plt1_e_p1.a, plt2_e_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: plt1_e_p1.a, plt1_e_p1.c, plt2_e_p1.b, plt2_e_p1.c
+ Hash Cond: ((plt1_e_p1.a = plt2_e_p1.b) AND (ltrim(plt1_e_p1.c, 'A'::text) = ltrim(plt2_e_p1.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ -> Seq Scan on public.plt2_e_p1
+ Output: plt2_e_p1.b, plt2_e_p1.c
+ Filter: ((plt2_e_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p2.a, plt1_e_p2.c, plt2_e_p2.b, plt2_e_p2.c
+ Hash Cond: ((plt1_e_p2.a = plt2_e_p2.b) AND (ltrim(plt1_e_p2.c, 'A'::text) = ltrim(plt2_e_p2.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ -> Seq Scan on public.plt2_e_p2
+ Output: plt2_e_p2.b, plt2_e_p2.c
+ Filter: ((plt2_e_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_e_p3.a, plt1_e_p3.c, plt2_e_p3.b, plt2_e_p3.c
+ Hash Cond: ((plt1_e_p3.a = plt2_e_p3.b) AND (ltrim(plt1_e_p3.c, 'A'::text) = ltrim(plt2_e_p3.c, 'A'::text)))
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ -> Seq Scan on public.plt2_e_p3
+ Output: plt2_e_p3.b, plt2_e_p3.c
+ Filter: ((plt2_e_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+-------+-----+-------
+ 0 | A0000 | 0 | A0000
+ 50 | A0001 | |
+ 100 | A0002 | |
+ 150 | A0003 | 150 | A0003
+ 200 | A0004 | |
+ 250 | A0005 | |
+ 300 | A0006 | 300 | A0006
+ 350 | A0007 | |
+ 400 | A0008 | |
+ 450 | A0009 | 450 | A0009
+ 500 | A0010 | |
+ 550 | A0011 | |
+ | | 75 | A0001
+ | | 225 | A0004
+ | | 375 | A0007
+ | | 525 | A0010
+(16 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+--
+-- negative testcases
+--
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out
index f06cfa4..16e7f56 100644
--- a/src/test/regress/expected/rangefuncs.out
+++ b/src/test/regress/expected/rangefuncs.out
@@ -1,18 +1,19 @@
SELECT name, setting FROM pg_settings WHERE name LIKE 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
CREATE TABLE foo2(fooid int, f2 int);
INSERT INTO foo2 VALUES(1, 11);
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 8641769..b61ca3b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -99,8 +99,9 @@ test: select_parallel
# ----------
# Another group of parallel tests
+# TODO: merge partition_join and multi_level_partition_join
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join multi_level_partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 835cf35..5b167b6 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -169,3 +169,5 @@ test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
+test: multi_level_partition_join
diff --git a/src/test/regress/sql/multi_level_partition_join.sql b/src/test/regress/sql/multi_level_partition_join.sql
new file mode 100644
index 0000000..e5895ce
--- /dev/null
+++ b/src/test/regress/sql/multi_level_partition_join.sql
@@ -0,0 +1,95 @@
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES START (0) END (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES START (0) END (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES START (0) END (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES START (100) END (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES START (250) END (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES START ('0250') END ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES START ('0400') END ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES START (500) END (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES START (1000) END (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES START (1100) END (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..b4945df
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,600 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES START (0) END (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES START (500) END (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES START (250) END (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES START (0) END (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES START (250) END (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES START (500) END (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND (t1.a + t2.b) % 120 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND (t1.a + t2.b) % 120 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND (t1.a + t2.b) % 120 = 0 ORDER BY t1.a, t2.b;
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 OR t2.b is null ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES START (0) END (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES START (250) END (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES START (500) END (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES START (0) END (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES START (250) END (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES START (500) END (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_a on prt1(a);
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_b on prt2(b);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_ab2 on prt1_e(((a+b)/2));
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES START (0, 0) END (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES START (250, 250) END (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES START (500, 500) END (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.a = t2.a AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.a AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM (SELECT 50 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t1.phv), avg(t2.b), t2.c, avg(t2.phv) FROM (SELECT 25 phv, * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.c = t2.c AND t1.a = t2.b) GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM plt1 t1, plt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, avg(t2.b), t2.c FROM uplt1 t1, uplt2 t2 WHERE t1.c = t2.c AND t1.c NOT IN ('0001', '0005', '0002', '0009') AND t2.c NOT IN ('0000', '0003', '0004', '0010') GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 LEFT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 RIGHT JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM plt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM plt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+SELECT sum(t1.a), t1.c, sum(t2.b), t2.c FROM (SELECT * FROM uplt1 t1 WHERE t1.c NOT IN ('0001', '0005', '0002', '0009')) t1 FULL JOIN (SELECT * FROM uplt2 t2 WHERE t2.c NOT IN ('0000', '0003', '0004', '0010')) t2 ON t1.c = t2.c GROUP BY t1.c, t2.c ORDER BY t1.c, t2.c;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+CREATE TABLE plt2_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt2_e_p1 PARTITION OF plt2_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_e_p2 PARTITION OF plt2_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_e_p3 PARTITION OF plt2_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2_e;
+ANALYZE plt2_e_p1;
+ANALYZE plt2_e_p2;
+ANALYZE plt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2_e AS SELECT * FROM plt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM plt1_e t1 LEFT JOIN plt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uplt1_e t1 LEFT JOIN uplt2_e t2 ON t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A') WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2_e WHERE plt2_e.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uplt1_e t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2_e t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND ltrim(t1.c, 'A') = ltrim(t2.c, 'A')) ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- negative testcases
+--
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES START ('0000') END ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES START ('0250') END ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES START (0) END (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES START (300) END (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES START (500) END (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
PFA patch rebased after partitioning code was committed.
On Thu, Dec 1, 2016 at 4:32 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
Hi Robert,
Sorry for delayed response.The attached patch implements following ideas:
1. At the time of creating paths - If the joining relations are both
partitioned and join can use partition-wise join, we create paths for
few child-joins. Similar to inheritance relations
(set_append_rel_pathlist()), we collect paths with similar properties
from all sampled child-joins and create one PartitionJoinPath with
each set of paths. The cost of the PartitionJoinPath is obtained by
multiplying the sum of costs of paths in the given set by the ratio of
(number of rows estimated in the parent-join/sum of rows in
child-joins).2. If the PartitionJoinPath emerges as the best path, we create paths
for each of the remaining child-joins. Then we collect paths with
properties same as the given PartitionJoinPath, one from each
child-join. These paths are converted into plans and a Merge/Append
plan is created combing these plans. The paths and plans for
child-join are created in a temporary memory context. The final plan
for each child-join is copied into planner's context and the temporary
memory context is reset.Right now, we choose 1% or 1 (whichever is higher) child-joins to base
PartitionJoinPath costs on.Memory consumption
-----------------------------
I tested a 5-way self-join for a table with 1000 partitions, each
partition having 1M rows. The memory consumed in standard_planner()
was measured with some granular tracking
(mem_usage_func_wise_measurement_slabwise.patch). Partition-wise join
consumed total of 289MB memory which is approx 6.6 times more than
non-partition-wise join which consumed 44MB. That's much better than
the earlier 16 times consumption for 5-way join with 100 partitions.The extra 245MB memory was consumed by child-join RelOptInfos (48MB),
SpecialJoinInfos for child-joins (64MB), restrictlist translation
(92MB), paths for sampled child-joins (1.5MB), building targetlists
for child-joins (7MB).
In the earlier implementation, a given clause which was applicable to
multiple join orders was getting translated as many times as the join
orders it was applicable in. I changed RestrictInfo for parent to
store a list of RestrictInfos applicable to children to avoid multiple
translations.
My earlier patch created the child-join plans in a temporary context
and then copied them into planner context since the translated clauses
were allocated memory in temporary memory context then. Now that they
are stored in planner's context, we can directly create the plan in
the planner's context.
Third, I added code to free up child SpecialJoinInfos after using those.
As a result the total memory consumption now is 192MB, which is approx
4.4 times the memory consumed during planning in case of
non-partition-wise join.
Choosing representative child-joins:
--------------------------------------------------
There's another angle to choosing representative child joins. In a
partitioned N-way join, different joins covering different subsets of
N relations, will have different size distributions across the
partitions. This means that the child-joins costed for (N-k) joins,
may be different for those required for (N-k+1) joins. With a factor
of 1% sampling, N is such that a child-join participates in 100 joins,
we will end up creating paths for all partitions before creating
PartitionJoinPaths for the final N-way join. Hopefully that will be a
rare case and usually we will end up using paths already created. We
can not avoid creating PartitionJoinPaths for subset joins, as there
might be cases when partition-wise join will be optimal for an N-k way
join but not for N-way join. We may avoid this if we choose
representative child-joins based on their positions, in which case, we
may end up with some or all of those being empty and thus skewing the
costs heavily.Partial paths
-----------------
AFAIU, we create partial paths for append relation, when all the
children have partial paths. Unlike parameterized paths or path with
pathkeys, there is no way to create a partial path for a normal path.
This means that unless we create paths for all child-joins, we can not
create partial paths for appendrel comprising of child-joins, and thus
can not use parallel query right now. This may not be that bad, since
it would be more efficient to run each child-join in a separate
worker, rather than using multiple workers for a single child-join.
This still applies.
regression tests
----------------------
I observed that for small relations (1000 rows in each partition and
100 partitions), the size estimates in append relations and sum of
those in child relations are very different. As a result, the
extrapolated costs for PartitionJoinPaths as described above, are way
higher than costs of join of appends (or even append of joins if we
are to create paths for all child-joins). Thus with this approach, we
choose partition-wise join for large number of partitions with large
data (e.g. 1000 partitions with 1M rows each). These are certainly the
cases when partition-wise join is a big win. I have not tried to find
out a threshold above which partition-wise join gets chosen with above
approach, but it's going to be a larger threshold. That makes writing
regression tests difficult, as those will require large data. So, we
have to find a way so that we can test partition-wise join with
smaller data. There are few possibilities like 1. convert the fraction
of representative child-joins into GUC and setting it to 100% would
start choosing partition-wise joins for tables with a few hundred rows
per partition, like it did in earlier approach, 2. provide a way to
force partition-wise join whenever possible, by say costing
partition-wise joins much lesser than non-partition-wise join when a
GUC is set (e.g. enable_partition_wise_join with values always, never,
optimal or something like that).
For now I have added a float GUC partition_wise_plan_weight. The
partition-wise join cost derived from the samples is multiplied by
this GUC and set as the cost of ParitionJoinPath. A value of 1 means
that the cost derived from the samples are used as is. A value higher
than 1 discourages use of partition-wise join and that lower than 1
encourages use of partition-wise join. I am not very keen on keeping
this GUC, in this form. But we need some way to run regression with
smaller data.
For now I have disabled partition-wise join for multi-level
partitions. I will post a patch soon with that enabled.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_v5.patchbinary/octet-stream; name=pg_dp_join_v5.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 66b059a..b1ea55a 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -911,7 +911,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
* We handle relations for foreign tables, joins between those and upper
* relations.
*/
- Assert(rel->reloptkind == RELOPT_JOINREL ||
+ Assert(IS_JOIN_REL(rel) ||
rel->reloptkind == RELOPT_BASEREL ||
rel->reloptkind == RELOPT_OTHER_MEMBER_REL ||
rel->reloptkind == RELOPT_UPPER_REL);
@@ -990,7 +990,7 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
@@ -1030,7 +1030,7 @@ deparseFromExpr(List *quals, deparse_expr_cxt *context)
/* For upper relations, scanrel must be either a joinrel or a baserel */
Assert(context->foreignrel->reloptkind != RELOPT_UPPER_REL ||
- scanrel->reloptkind == RELOPT_JOINREL ||
+ IS_JOIN_REL(scanrel) ||
scanrel->reloptkind == RELOPT_BASEREL);
/* Construct FROM clause */
@@ -1178,7 +1178,7 @@ deparseLockingClause(deparse_expr_cxt *context)
appendStringInfoString(buf, " FOR UPDATE");
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(rel))
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
else
@@ -1345,7 +1345,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
RelOptInfo *rel_o = fpinfo->outerrel;
RelOptInfo *rel_i = fpinfo->innerrel;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index fbe6929..7b3d8bb 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -721,8 +721,8 @@ get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel)
return useful_eclass_list;
/* If this is a child rel, we must use the topmost parent rel to search. */
- if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
- relids = find_childrel_top_parent(root, rel)->relids;
+ if (IS_OTHER_REL(rel))
+ relids = find_childrel_top_parent(root, rel);
else
relids = rel->relids;
@@ -1183,7 +1183,7 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
@@ -1249,7 +1249,7 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel->reloptkind) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2529,7 +2529,7 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
@@ -2611,7 +2611,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind == RELOPT_JOINREL)
+ else if (IS_JOIN_REL(foreignrel))
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index 9980582..41ffc94 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -20,6 +20,7 @@
#include "access/nbtree.h"
#include "access/sysattr.h"
#include "catalog/dependency.h"
+#include "catalog/heap.h"
#include "catalog/indexing.h"
#include "catalog/objectaddress.h"
#include "catalog/partition.h"
@@ -139,6 +140,8 @@ static int32 partition_bound_cmp(PartitionKey key,
static int partition_bound_bsearch(PartitionKey key,
PartitionBoundInfo boundinfo,
void *probe, bool probe_is_bound, bool *is_equal);
+static PartitionBoundInfo partition_bounds_copy(PartitionBoundInfo src,
+ PartitionKey key);
/* Support get_partition_for_tuple() */
static void FormPartitionKeyDatum(PartitionDispatch pd,
@@ -1942,3 +1945,250 @@ partition_bound_bsearch(PartitionKey key, PartitionBoundInfo boundinfo,
return lo;
}
+
+ /*
+ * Return a copy of given PartitionBoundInfo structure. The data types of bounds
+ * are described by given partition key specificiation.
+ */
+static PartitionBoundInfo
+partition_bounds_copy(PartitionBoundInfo src, PartitionKey key)
+{
+ PartitionBoundInfo dest;
+ int i;
+ int ndatums;
+ int partnatts;
+ int num_indexes;
+
+ dest = (PartitionBoundInfo) palloc(sizeof(PartitionBoundInfoData));
+
+ dest->strategy = src->strategy;
+ ndatums = dest->ndatums = src->ndatums;
+ partnatts = key->partnatts;
+
+ /* Range partitioned table has an extra index. */
+ num_indexes = key->strategy == PARTITION_STRATEGY_RANGE ? ndatums + 1 : ndatums;
+
+ /* List partitioned tables have only a single partition key. */
+ Assert(key->strategy != PARTITION_STRATEGY_LIST || partnatts == 1);
+
+ dest->datums = (Datum **) palloc(sizeof(Datum *) * ndatums);
+
+ for (i = 0; i < ndatums; i++)
+ {
+ int j;
+ dest->datums[i] = (Datum *) palloc(sizeof(Datum) * partnatts);
+
+ for (j = 0; j < partnatts; j++)
+ dest->datums[i][j] = datumCopy(src->datums[i][j],
+ key->parttypbyval[j],
+ key->parttyplen[j]);
+ }
+
+ if (src->content)
+ {
+ dest->content = (RangeDatumContent **) palloc(ndatums *
+ sizeof(RangeDatumContent *));
+ for (i = 0; i < ndatums; i++)
+ {
+ dest->content[i] = (RangeDatumContent *) palloc(partnatts *
+ sizeof(RangeDatumContent));
+
+ memcpy(dest->content[i], src->content[i],
+ sizeof(RangeDatumContent) * key->partnatts);
+ }
+ }
+ else
+ dest->content = NULL;
+
+ dest->indexes = (int *) palloc(sizeof(int) * num_indexes);
+ memcpy(dest->indexes, src->indexes, sizeof(int) * num_indexes);
+
+ dest->has_null = src->has_null;
+ dest->null_index = src->null_index;
+
+ return dest;
+}
+
+/*
+ * find_partition_scheme
+ *
+ * The function returns a canonical partition scheme which exactly matches the
+ * partitioning properties of the given relation if one exists in the of
+ * canonical partitioning schemes maintained in PlannerInfo. If none of the
+ * existing partitioning schemes match, the function creates a canonical
+ * partition scheme and adds it to the list.
+ *
+ * For an unpartitioned table or for a multi-level partitioned table it returns
+ * NULL.
+ */
+extern PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ int cnt_parts;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /*
+ * For a multi-level partitioned table, we do not retain the partitioning
+ * hierarchy while expanding RTE for the topmost parent. Thus the number of
+ * children as per root->append_rel_list does not match the number of
+ * partitions specified in the partition descriptor and hence the
+ * partitioning scheme of a multi-partitioned table does not reflect the
+ * true picture. So for now, treat a multi-partitioned table as not
+ * partitioned.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (has_subclass(part_desc->oids[cnt_parts]))
+ return NULL;
+ }
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * For types, it suffices to match the type id, mod and collation;
+ * len, byval and align are depedent on the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->parttypid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->parttypmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->parttypcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->boundinfo,
+ part_scheme->boundinfo))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->boundinfo = partition_bounds_copy(part_desc->boundinfo,
+ part_key);
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopfamily, part_key->partopfamily,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopcintype, part_key->partopcintype,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_types, part_key->parttypid,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ memcpy(part_scheme->key_typmods, part_key->parttypmod,
+ sizeof(int32) * partnatts);
+
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_collations, part_key->parttypcoll,
+ sizeof(Oid) * partnatts);
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_key_exprs
+ *
+ * Collect partition key expressions for a given base relation. The function
+ * converts any single column partition keys into corresponding Var nodes. It
+ * restamps Var nodes in partition key expressions by given varno. The
+ * partition key expressions are returned as an array of single element Lists
+ * to be stored in RelOptInfo of the base relation.
+ */
+extern List **
+build_baserel_partition_key_exprs(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (lc == NULL)
+ elog(ERROR, "wrong number of partition key expressions");
+
+ /* Re-stamp the expressions with given varno. */
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 242d6d2..75c95e4 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -721,7 +721,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
{
ListCell *lc;
- Assert(joinrel->reloptkind == RELOPT_JOINREL);
+ Assert(IS_JOIN_REL(joinrel));
foreach(lc, joinrel->pathlist)
{
@@ -786,7 +786,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->outerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->outerjoinpath = foreign_path->fdw_outerpath;
}
@@ -795,7 +795,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->innerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->innerjoinpath = foreign_path->fdw_outerpath;
}
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index d973225..fa0569c 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2049,6 +2049,14 @@ _copyRestrictInfo(const RestrictInfo *from)
COPY_SCALAR_FIELD(hashjoinoperator);
COPY_SCALAR_FIELD(left_bucketsize);
COPY_SCALAR_FIELD(right_bucketsize);
+ /*
+ * Do not copy parent_rinfo and child_rinfos because 1. they create a
+ * circular dependency between child and parent RestrictInfo 2. dropping
+ * those links just means that we loose some memory optimizations. 3. There
+ * is a possibility that the child and parent RestrictInfots themselves may
+ * have got copied and thus the old links may no longer be valid. The
+ * caller may set up those links itself, if needed.
+ */
return newnode;
}
diff --git a/src/backend/optimizer/README b/src/backend/optimizer/README
index 775bcc3..d755f1f 100644
--- a/src/backend/optimizer/README
+++ b/src/backend/optimizer/README
@@ -974,3 +974,56 @@ be desirable to postpone the Gather stage until as near to the top of the
plan as possible. Expanding the range of cases in which more work can be
pushed below the Gather (and costing them accurately) is likely to keep us
busy for a long time to come.
+
+Partition-wise joins
+--------------------
+A join between two similarly partitioned tables can be broken down into joins
+between their matching partitions if there exists an equi-join condition
+between the partition keys of the joining tables. The equi-join between
+partition keys implies that for a given row in a given partition of a given
+partitioned table, its joining row, if exists, should exist only in the
+matching partition of the other partitioned table; no row from non-matching
+partitions in the other partitioned table can join with the given row from the
+first table. This condition allows the join between partitioned table to be
+broken into joins between the matching partitions. The resultant join is
+partitioned in the same way as the joining relations, thus allowing an N-way
+join between similarly partitioned tables having equi-join condition between
+their partition keys to be broken down into N-way joins between their matching
+partitions. This technique of breaking down a join between partition tables
+into join between their partitions is called partition-wise join. We will use
+term "partitioned relation" for both partitioned table as well as join between
+partitioned tables which can use partition-wise join technique.
+
+Partitioning properties of a partitioned table are stored in
+PartitionSchemeData structure. Planner maintains a list of canonical partition
+schemes (distinct PartitionSchemeData objects) so that any two partitioned
+relations with same partitioning scheme share the same PartitionSchemeData
+object. This reduces memory consumed by PartitionSchemeData objects and makes
+it easy to compare the partition schemes of joining relations. RelOptInfos of
+partitioned relations hold partition key expressions and the RelOptInfos of
+the partition relations of that relation.
+
+Partition-wise joins are planned in two phases
+
+1. First phase creates the RelOptInfos for joins between matching partitions,
+henceforth referred to as child-joins. The number of paths created for a
+child-join i.e. join between partitions is same as the number of paths created
+for join between parents. That number grows exponentially with the number of
+base relations being joined. The time and memory consumed to create paths for
+each child-join will be proporional to the number of partitions. This will not
+scale well with thousands of partitions. Instead of that we estimate
+partition-wise join cost based on the costs of sampled child-joins. We choose
+child-joins with higher sizes to have realistic estimates. If the number of
+sampled child-joins is same as the number of live child-joins, we create append
+paths as we know costs of all required child-joins. Otherwise we create
+PartitionJoinPaths with cost estimates based on the costs of sampled
+child-joins. While creating append paths or PartitionJoin paths we create paths
+for all the different possible parameterizations and pathkeys available in the
+sampled child-joins.
+
+2. If PartitionJoinPath emerges as the best possible path, we create paths for
+each unsampled child-join. From every child-join we choose the cheapest path
+with same parameterization or pathkeys as the PartitionJoinPath. This path is
+converted into a plan and all the child-join plans are combined using an Append
+or MergeAppend plan as appropriate. We use a fresh memory context for planning
+each unsampled child-join, thus reducing memory consumption.
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 9753a26..0a2c131 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -18,8 +18,10 @@
#include <limits.h>
#include <math.h>
+#include "miscadmin.h"
#include "access/sysattr.h"
#include "access/tsmapi.h"
+#include "catalog/partition.h"
#include "catalog/pg_class.h"
#include "catalog/pg_operator.h"
#include "catalog/pg_proc.h"
@@ -44,6 +46,7 @@
#include "parser/parsetree.h"
#include "rewrite/rewriteManip.h"
#include "utils/lsyscache.h"
+#include "utils/rel.h"
/* results of subquery_is_pushdown_safe */
@@ -93,8 +96,8 @@ static void set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
static void set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
static void generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels,
- List *all_child_pathkeys);
+ List *live_childrels, List *all_child_pathkeys,
+ bool partition_join_path);
static Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
RelOptInfo *rel,
Relids required_outer);
@@ -126,6 +129,8 @@ static void subquery_push_qual(Query *subquery,
static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels, bool partition_join_path);
/*
@@ -868,6 +873,34 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ Oid *part_oids = NULL;
+ int nparts = 0;
+
+ /*
+ * We require OIDs of the partitions to arrange the child RelOptInfos to
+ * match the lists/ranges specified in the partitioning scheme. Fetch those
+ * here so as keep those handy when going to child RelOptInfos below.
+ */
+ if (rel->part_scheme)
+ {
+ RangeTblEntry *rte = root->simple_rte_array[rel->relid];
+
+ /*
+ * We need not lock the relation since it was already locked, either by
+ * the rewriter or when expand_inherited_rtentry() added it to the
+ * query's rangetable.
+ */
+ Relation relation = heap_open(rte->relid, NoLock);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+
+ part_oids = part_desc->oids;
+ nparts = part_desc->nparts;
+
+ Assert(part_oids && nparts > 0);
+
+ rel->part_rels = (RelOptInfo **)palloc0(sizeof(RelOptInfo *) * nparts);
+ heap_close(relation, NoLock);
+ }
/*
* Initialize to compute size estimates for whole append relation.
@@ -899,6 +932,8 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Node *childqual;
ListCell *parentvars;
ListCell *childvars;
+ int cnt_parts;
+ List *appinfos = list_make1(appinfo);
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -912,8 +947,95 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* add_base_rels_to_query.
*/
childrel = find_base_rel(root, childRTindex);
+
+ /*
+ * Recursively save topmost parent's relid in RelOptInfos of
+ * partitions.
+ */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
+ /*
+ * For two partitioned tables with the same partitioning scheme, it is
+ * assumed that the Oids of matching partitions from both the tables
+ * are placed at the same position in the array of partition oids in
+ * respective partition descriptors. Saving the RelOptInfo of a
+ * partition in the same cardinal position as its Oid makes it easy to
+ * find the RelOptInfos of matching partitions for partition-wise join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+
+ /*
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for building pair-wise
+ * join relations. Partition tables should have same layout as the
+ * parent table and hence should not need any translation. But rest of
+ * the code still uses inheritance mechanism. So does this code. For
+ * other inherited children, attr_needed is only examined for base
+ * relations, no otherrels. So we compute attr_needed only for children
+ * of a partitioned table.
+ */
+ if (rel->part_scheme)
+ {
+ AttrNumber attno;
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /* Parent Var translates to child Var. */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
+ }
+
+ /*
+ * Copy/Modify targetlist. Even if this child is deemed empty, we need
+ * its targetlist in case it falls on nullable side in a child-join
+ * because of partition-wise join.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs, appinfos);
+
/*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
@@ -931,7 +1053,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childquals = get_all_actual_clauses(rel->baserestrictinfo);
childquals = (List *) adjust_appendrel_attrs(root,
(Node *) childquals,
- appinfo);
+ appinfos);
childqual = eval_const_expressions(root, (Node *)
make_ands_explicit(childquals));
if (childqual && IsA(childqual, Const) &&
@@ -960,24 +1082,9 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
- childrel->joininfo = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->joininfo,
- appinfo);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo);
+ /* CE failed, so finish copying/modifying join quals. */
+ childrel->joininfo = build_child_clauses(root, rel->joininfo,
+ appinfos);
/*
* We have to make child entries in the EquivalenceClass data
@@ -992,14 +1099,6 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
- * Note: we could compute appropriate attr_needed data for the child's
- * variables, by transforming the parent's attr_needed through the
- * translated_vars mapping. However, currently there's no need
- * because attr_needed is only examined for base relations not
- * otherrels. So we just leave the child's attr_needed empty.
- */
-
- /*
* If parallelism is allowable for this query in general, see whether
* it's allowable for this childrel in particular. But if we've
* already decided the appendrel is not parallel-safe as a whole,
@@ -1080,6 +1179,16 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ if (!rel->part_rels[cnt_parts])
+ elog(ERROR, "could not find the RelOptInfo of a partition with oid %u",
+ part_oids[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
@@ -1122,19 +1231,11 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
- * Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * Generate access paths for each member relation and remember the
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
@@ -1142,7 +1243,6 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -1177,6 +1277,64 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ /* Add Append/MergeAppend paths to the "append" relation. */
+ add_paths_to_append_rel(root, rel, live_childrels, false);
+}
+
+/*
+ * add_paths_to_append_rel
+ * Generate Append/MergeAppend paths for given "append" relation. An
+ * "append" relation can be a base parent relation or a join between
+ * partitioned tables.
+ *
+ * The function collects all parameterizations and orderings supported by the
+ * non-dummy children. For every such parameterization or ordering, it creates
+ * an append path collecting one path from each non-dummy child with given
+ * parameterization or ordering. Similarly it collects partial paths from
+ * non-dummy children to create partial append paths.
+ */
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels, bool partition_join_path)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * While creating PartitionJoinPath, we sample paths from only a few child
+ * relations. Even if all of sampled children have partial paths, it's not
+ * guaranteed that all the unsampled children will have partial paths.
+ * Hence we do not create partial PartitionJoinPaths.
+ */
+ partial_subpaths_valid = !partition_join_path ? true : false;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (live_childrels == NIL)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
@@ -1267,7 +1425,17 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(rel, subpaths,
+ NULL);
+ else
+ path = (Path *) create_append_path(rel, subpaths, NULL, 0);
+
+ add_path(rel, path);
+ }
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1278,6 +1446,8 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
ListCell *lc;
int parallel_workers = 0;
+ Assert(!partition_join_path);
+
/*
* Decide on the number of workers to request for this append path.
* For now, we just use the maximum value from among the members. It
@@ -1304,7 +1474,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
*/
if (subpaths_valid)
generate_mergeappend_paths(root, rel, live_childrels,
- all_child_pathkeys);
+ all_child_pathkeys, partition_join_path);
/*
* Build Append paths for each parameterization seen among the child rels.
@@ -1345,8 +1515,16 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(rel, subpaths, required_outer);
+ else
+ path = (Path *) create_append_path(rel, subpaths, required_outer, 0);
+
+ add_path(rel, path);
+ }
}
}
@@ -1376,7 +1554,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
static void
generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *live_childrels,
- List *all_child_pathkeys)
+ List *all_child_pathkeys, bool partition_join_path)
{
ListCell *lcp;
@@ -1387,6 +1565,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *total_subpaths = NIL;
bool startup_neq_total = false;
ListCell *lcr;
+ Path *path;
/* Select the child paths for this ordering... */
foreach(lcr, live_childrels)
@@ -1434,17 +1613,29 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
}
/* ... and build the MergeAppend paths */
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- startup_subpaths,
- pathkeys,
- NULL));
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path_with_pathkeys(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+
if (startup_neq_total)
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- total_subpaths,
- pathkeys,
- NULL));
+ {
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path_with_pathkeys(root,
+ rel,
+ total_subpaths,
+ pathkeys, NULL);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ total_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+ }
}
}
@@ -2186,15 +2377,27 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
/*
* Run generate_gather_paths() for each just-processed joinrel. We
- * could not do this earlier because both regular and partial paths
- * can get added to a particular joinrel at multiple times within
- * join_search_one_level. After that, we're done creating paths for
- * the joinrel, so run set_cheapest().
+ * could not do this earlier because both regular and partial paths can
+ * get added to a particular joinrel at multiple times within
+ * join_search_one_level.
+ *
+ * Similarly, create paths for joinrels which used partition-wise join
+ * technique. generate_partition_wise_join_paths() creates paths for
+ * only few of the child-joins with highest sizes. Though we calculate
+ * size of a child-join only once; when it gets created, it may be
+ * deemed empty while considering various join orders within
+ * join_search_one_level.
+ *
+ * After that, we're done creating paths for the joinrel, so run
+ * set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
rel = (RelOptInfo *) lfirst(lc);
+ /* Create paths for partition-wise joins. */
+ generate_partition_wise_join_paths(root, rel);
+
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
@@ -2866,6 +3069,151 @@ remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel)
}
}
+/* Fraction of child relations to base cost on. */
+#define FRACTION_PARTS_TO_PLAN 0.01
+
+/*
+ * generate_partition_wise_join_paths
+ *
+ * Create paths representing partition-wise join for given partitioned
+ * join relation.
+ *
+ * The number of paths created for a child-join is same as the number of paths
+ * created for join between parents. That number grows exponentially with the
+ * number of base relations being joined. The time and memory consumed to
+ * create paths for each child-join will be proporional to the number of
+ * partitions. This will not scale well with thousands of partitions. Instead
+ * of that we estimate partition-wise join cost based on the costs of sampled
+ * child-joins. We choose child-joins with higher sizes to have realistic
+ * estimates.
+ *
+ * This must be called after we have considered all joining orders since
+ * certain join orders may allow us to deem a child-join as dummy.
+ */
+void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *sampled_children = NIL;
+ List *ordered_child_nos = NIL;
+ int cnt_part;
+ int num_part_to_plan;
+ int num_parts;
+ bool partition_join_path = false;
+ int num_dummy_parts = 0;
+ ListCell *lc;
+
+ /* Handle only join relations. */
+ if (!IS_JOIN_REL(rel))
+ return;
+
+ /*
+ * If none of the join orders for this relation could use partition-wise
+ * join technique, the join is not partitioned. Reset the partitioning
+ * scheme.
+ */
+ if (!rel->part_rels)
+ rel->part_scheme = NULL;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || IS_DUMMY_REL(rel))
+ return;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ num_parts = rel->part_scheme->nparts;
+
+ /* Calculate number of child-joins to sample. */
+ num_part_to_plan = num_parts * FRACTION_PARTS_TO_PLAN;
+ if (num_part_to_plan < 1)
+ num_part_to_plan = 1;
+
+ /* Order the child-join relations by their size. */
+ for (cnt_part = 0; cnt_part < num_parts; cnt_part++)
+ {
+ RelOptInfo *child_rel = rel->part_rels[cnt_part];
+ ListCell *insert_after;
+
+ insert_after = NULL;
+
+ /* Dummy children will not be scanned, so ingore those. */
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+ /*
+ * Add this relation to the list of samples ordered by the increasing
+ * number of rows at appropriate place.
+ */
+ foreach (lc, ordered_child_nos)
+ {
+ int child_no = lfirst_int(lc);
+ RelOptInfo *other_childrel = rel->part_rels[child_no];
+
+ /*
+ * Keep track of child with lowest number of rows but higher than the
+ * that of the child being inserted. Insert the child before a
+ * child with highest number of rows lesser than it.
+ */
+ if (child_rel->rows <= other_childrel->rows)
+ insert_after = lc;
+ else
+ break;
+ }
+
+ if (insert_after)
+ lappend_cell_int(ordered_child_nos, insert_after, cnt_part);
+ else
+ ordered_child_nos = lcons_int(cnt_part, ordered_child_nos);
+ }
+
+ /*
+ * Create paths for the child-joins as they appear in the list ordered by
+ * their size. Stop when we have created paths for required number of
+ * child-joins.
+ */
+ foreach (lc, ordered_child_nos)
+ {
+ int child_no = lfirst_int(lc);
+ RelOptInfo *child_rel = rel->part_rels[child_no];
+
+ /* Create paths for this child. */
+ add_paths_to_child_joinrel(root, rel, child_no);
+
+ /* Dummy children will not be scanned, so ingore those. */
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ sampled_children = lappend(sampled_children, child_rel);
+
+ if (list_length(sampled_children) >= num_part_to_plan)
+ break;
+ }
+
+ /*
+ * If the number of samples is same as the number of live children, an
+ * append path will do. Otherwise, we will cost the partition-wise join
+ * based on the sampled children using PartitionJoinPath.
+ */
+ if (num_part_to_plan < num_parts - num_dummy_parts)
+ partition_join_path = true;
+
+ /* Add paths for partition-wise join based on the sampled children. */
+ add_paths_to_append_rel(root, rel, sampled_children, partition_join_path);
+
+ if (sampled_children)
+ list_free(sampled_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
*****************************************************************************/
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 415edad..ba2b238 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,8 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
+double partition_wise_plan_weight = DEFAULT_PARTITION_WISE_PLAN_WEIGHT;
typedef struct
{
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index 0e50ad5..b1ea2ba 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -972,6 +972,10 @@ generate_base_implied_equalities_broken(PlannerInfo *root,
* appropriate clauses using child EC members. add_child_rel_equivalences
* must already have been done for the child rel.
*
+ * For a join between child relations, joinrelids, outer_relids and
+ * inner_rel all point to child relations. In this case, we need to find the
+ * parent relids to search the applicable equivalence classes.
+ *
* The results are sufficient for use in merge, hash, and plain nestloop join
* methods. We do not worry here about selecting clauses that are optimal
* for use in a parameterized indexscan. indxpath.c makes its own selections
@@ -1021,12 +1025,27 @@ generate_join_implied_equalities_for_ecs(PlannerInfo *root,
ListCell *lc;
/* If inner rel is a child, extra setup work is needed */
- if (inner_rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ if (IS_OTHER_REL(inner_rel))
{
+ RelOptInfo *outer_rel;
+ Relids nominal_outer_relids;
+
+ if (bms_num_members(outer_relids) > 1)
+ outer_rel = find_join_rel(root, outer_relids);
+ else
+ outer_rel = find_base_rel(root, bms_singleton_member(outer_relids));
+
/* Fetch relid set for the topmost parent rel */
- nominal_inner_relids = find_childrel_top_parent(root, inner_rel)->relids;
- /* ECs will be marked with the parent's relid, not the child's */
- nominal_join_relids = bms_union(outer_relids, nominal_inner_relids);
+ nominal_inner_relids = find_childrel_top_parent(root, inner_rel);
+
+ /* ECs will be marked with the parent's relid, not the child's. */
+ if (outer_rel && IS_OTHER_REL(outer_rel))
+ {
+ nominal_outer_relids = find_childrel_top_parent(root, outer_rel);
+ nominal_join_relids = bms_union(nominal_outer_relids, nominal_inner_relids);
+ }
+ else
+ nominal_join_relids = bms_union(outer_relids, nominal_inner_relids);
}
else
{
@@ -2062,7 +2081,7 @@ add_child_rel_equivalences(PlannerInfo *root,
child_expr = (Expr *)
adjust_appendrel_attrs(root,
(Node *) cur_em->em_expr,
- appinfo);
+ list_make1(appinfo));
/*
* Transform em_relids to match. Note we do *not* do
@@ -2364,8 +2383,8 @@ eclass_useful_for_merging(PlannerInfo *root,
*/
/* If specified rel is a child, we must consider the topmost parent rel */
- if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
- relids = find_childrel_top_parent(root, rel)->relids;
+ if (IS_OTHER_REL(rel))
+ relids = find_childrel_top_parent(root, rel);
else
relids = rel->relids;
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index 96f00fc..efa4af0 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -25,9 +25,19 @@
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+/*
+ * Paths parameterized by the parent can be considered to be parameterized by
+ * any of its child.
+ */
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
@@ -132,6 +142,19 @@ add_paths_to_joinrel(PlannerInfo *root,
foreach(lc, root->join_info_list)
{
SpecialJoinInfo *sjinfo2 = (SpecialJoinInfo *) lfirst(lc);
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between child relations, even if there is a SpecialJoinInfo node for
+ * the join between the topmost parents. Hence while calculating Relids
+ * set representing the restriction, consider relids of topmost parent
+ * of partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
/*
* SJ is relevant to this join if we have some part of its RHS
@@ -140,16 +163,16 @@ add_paths_to_joinrel(PlannerInfo *root,
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo2->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo2->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo2->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo2->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_righthand))
+ bms_overlap(joinrelids, sjinfo2->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_lefthand));
@@ -279,6 +302,22 @@ try_nestloop_path(PlannerInfo *root,
JoinCostWorkspace workspace;
/*
+ * For a join between child relations, if the inner path is parameterized
+ * by the parent of the outer relation, create a nestloop join path with
+ * inner relation parameterized by the outer relation by translating the
+ * inner path to be parameterized by the outer child relation.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_by_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..47ff915 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -14,9 +14,14 @@
*/
#include "postgres.h"
+#include "miscadmin.h"
+#include "catalog/partition.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
@@ -32,7 +37,19 @@ static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
-
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
/*
* join_search_one_level
@@ -724,6 +741,31 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Add paths to the given joinrel for given pair of joining relations. The
+ * SpecialJoinInfo provides details about the join and the restrictlist
+ * contains the join clauses and the other clauses applicable for given pair
+ * of the joining relations.
+ */
+
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
@@ -868,13 +910,8 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
-
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
@@ -1249,3 +1286,477 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
}
return false;
}
+
+/* Free SpecialJoinInfo. */
+static void
+free_special_join_info(SpecialJoinInfo *sjinfo)
+{
+ bms_free(sjinfo->min_lefthand);
+ bms_free(sjinfo->syn_lefthand);
+ bms_free(sjinfo->syn_righthand);
+ pfree(sjinfo);
+}
+
+/*
+ * Assess whether join between given two partitioned relations can be broken
+ * down into joins between matching partitions; a technique called
+ * "partition-wise join"
+ *
+ * Partition-wise join is possible when a. Joining relations have same
+ * partitioning scheme b. There exists an equi-join between the partition keys
+ * of the two relations.
+ *
+ * Partition-wise join is planned as follows (details: optimizer/README.)
+ *
+ * 1. Create the RelOptInfos for joins between matching partitions i.e
+ * child-joins and estimate sizes of those. This function is responsible for
+ * this phase.
+ *
+ * 2. Add paths representing partition-wise join. The second phase is
+ * implemented by generate_partition_wise_join_paths(). In order to save time
+ * and memory consumed in creating paths for every child-join, we create paths
+ * for only few child-joins.
+ *
+ * 3. Create merge/append plan to combining plans for every child-join,
+ * creating paths for remaining child-joins.
+ *
+ * The RelOptInfo, SpecialJoinInfo and restrictlist for each child join are
+ * obtained by translating the respective parent join structures.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ PartitionScheme part_scheme;
+ PartitionedJoin *partitioned_join;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If any of the joining parent relations is proven empty, either the join
+ * will be empty (INNER join) or will have the inner side all nullified. We
+ * take care of such cases when creating join paths for parent relations.
+ * Nothing to be done here. Also, nothing to do, if the parent join is
+ * proven empty.
+ */
+ if (IS_DUMMY_REL(rel1) || IS_DUMMY_REL(rel2) || IS_DUMMY_REL(joinrel))
+ return;
+
+ /*
+ * Partitioning scheme in join relation indicates a possibilty that the
+ * join may be partitioned, but it's not necessary that every pair of
+ * joining relations can use partition-wise join technique. If one of
+ * joining relations turns out to be unpartitioned, this pair of joining
+ * relations can not use partition-wise join technique.
+ */
+ if (!rel1->part_scheme || !rel2->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, this pair of joining relations can not use
+ * partition-wise technique.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ /*
+ * The partition scheme of the join relation should match that of the
+ * joining relations.
+ */
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ /* We should have RelOptInfos of the partitions available. */
+ Assert(rel1->part_rels && rel2->part_rels);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = part_scheme->nparts;
+
+ /*
+ * We do not store information about valid pairs of joining child
+ * relations. The pair of joining relations for a child-join can be derived
+ * from valid pairs of joining parent relations. Amongst the valid pairs of
+ * parent joining relations, only those which result in partitioned join
+ * matter for partition-wise join. Remember those so that we can use them
+ * for creating paths for few child-joins in
+ * generate_partition_wise_join_paths() later.
+ */
+ partitioned_join = (PartitionedJoin *) palloc(sizeof(PartitionedJoin));
+ partitioned_join->rel1 = rel1;
+ partitioned_join->rel2 = rel2;
+ partitioned_join->sjinfo = copyObject(parent_sjinfo);
+ joinrel->partitioned_joins = lappend(joinrel->partitioned_joins,
+ partitioned_join);
+
+ elog(DEBUG3, "join between relations %s and %s is considered for partition-wise join.",
+ bmsToString(rel1->relids), bmsToString(rel2->relids));
+
+ /* We are done if child RelOptInfos are already created. */
+ if (joinrel->part_rels)
+ return;
+
+ /* Create all the child RelOptInfos. */
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create child join relations for this partitioned join. While doing so,
+ * we estimate sizes of these child join relations. These estimates are
+ * used to find the representative child relations used for costing the
+ * partition-wise join later.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ RelOptInfo *child_joinrel;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ Assert (!joinrel->part_rels[cnt_parts]);
+
+ child_joinrel = build_child_join_rel(root, child_rel1, child_rel2,
+ joinrel, parent_sjinfo->jointype);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_joinrel_restrictlist(root,
+ child_joinrel,
+ child_rel1,
+ child_rel2);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, parent_sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+ /*
+ * Set estimates of the child-joinrel's size.
+ */
+ set_joinrel_size_estimates(root, child_joinrel, child_rel1, child_rel2,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the child relations themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+}
+
+/*
+ * add_paths_to_child_join
+ * Add paths to 'child_id'th child of given parent join relation.
+ *
+ * The function creates paths for given child-join by joining corresponding
+ * children of every pair of joining parent relations which produces
+ * partitioned join. Since we create paths only for sampled child-joins, either
+ * of the children being joined may not have paths. In that case, this function
+ * is called recursively to populate paths for those.
+ */
+void
+add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
+ int child_id)
+{
+ ListCell *lc;
+ RelOptInfo *child_joinrel = parent_joinrel->part_rels[child_id];
+
+ Assert(IS_JOIN_REL(parent_joinrel));
+
+ /* If this child relation already has paths, nothing to do. */
+ if (child_joinrel->cheapest_total_path)
+ return;
+
+ /* A dummy relation will have a dummy path as the cheapest path. */
+ Assert(!is_dummy_rel(child_joinrel));
+
+ /*
+ * For every partitioned join order, calculate paths for the joining
+ * child relations and then calculate paths for given child.
+ */
+ foreach (lc, parent_joinrel->partitioned_joins)
+ {
+ PartitionedJoin *pj = lfirst(lc);
+ RelOptInfo *rel1 = pj->rel1;
+ RelOptInfo *rel2 = pj->rel2;
+ RelOptInfo *child_rel1 = rel1->part_rels[child_id];
+ RelOptInfo *child_rel2 = rel2->part_rels[child_id];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+
+ /*
+ * Add paths to joining relation if it is a join itself.
+ * Paths for child base relations are created in
+ * set_append_rel_pathlist().
+ */
+ if (IS_JOIN_REL(pj->rel1))
+ add_paths_to_child_joinrel(root, rel1, child_id);
+
+ if (IS_JOIN_REL(pj->rel2))
+ add_paths_to_child_joinrel(root, rel2, child_id);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, pj->sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_joinrel_restrictlist(root,
+ child_joinrel,
+ child_rel1,
+ child_rel2);
+
+ /* Add paths for child join. */
+ populate_joinrel_with_paths(root, rel1->part_rels[child_id],
+ rel2->part_rels[child_id], child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /* Add partition-wise join paths for partitioned child-joins. */
+ generate_partition_wise_join_paths(root, child_joinrel);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+
+ set_cheapest(child_joinrel);
+}
+
+/*
+ * Construct the SpecialJoinInfo for a child-join by translating
+ * SpecialJoinInfo for the join between parents. left_relids and right_relids
+ * are the relids of left and right side of the join respectively.
+ */
+static SpecialJoinInfo *
+build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids)
+{
+ SpecialJoinInfo *sjinfo = makeNode(SpecialJoinInfo);
+ MemoryContext old_context;
+ List *left_appinfos = find_appinfos_by_relids(root, left_relids);
+ List *right_appinfos = find_appinfos_by_relids(root, right_relids);
+
+ memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
+
+ sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
+ left_appinfos);
+ sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
+ right_appinfos);
+ sjinfo->syn_lefthand = adjust_child_relids(sjinfo->syn_lefthand,
+ left_appinfos);
+ sjinfo->syn_righthand = adjust_child_relids(sjinfo->syn_righthand,
+ right_appinfos);
+
+ /*
+ * Replace the Var nodes of parent with those of children in expressions.
+ * This function may be called within a temporary context, but the
+ * expressions will be shallow-copied into the plan. Hence copy those in
+ * the planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ sjinfo->semi_rhs_exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ right_appinfos);
+ MemoryContextSwitchTo(old_context);
+
+ list_free(left_appinfos);
+ list_free(right_appinfos);
+
+ return sjinfo;
+}
+
+/*
+ * Replace parent relids by child relids in the copy of given relid set.
+ */
+Relids
+adjust_child_relids(Relids relids, List *append_rel_infos)
+{
+ ListCell *lc;
+
+ /* Ensure we have a modifiable copy. */
+ relids = bms_copy(relids);
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ /* Remove parent, add child */
+ if (bms_is_member(appinfo->parent_relid, relids))
+ {
+ relids = bms_del_member(relids, appinfo->parent_relid);
+ relids = bms_add_member(relids, appinfo->child_relid);
+ }
+ }
+
+ return relids;
+}
+
+/*
+ * Returns true if there exists an equi-join condition for each pair of
+ * partition key from given relations being joined.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ /*
+ * This function should be called when the joining relations have same
+ * partitioning scheme.
+ */
+ Assert(rel1->part_scheme == rel2->part_scheme);
+ Assert(part_scheme);
+
+ num_pks = part_scheme->partnatts;
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip clauses which can not be used for a join. */
+ if (!rinfo->can_join)
+ continue;
+
+ /* Skip clauses which are not equality conditions. */
+ if (rinfo->hashjoinoperator == InvalidOid && !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+
+ /* Match the operands to the relation. */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ /*
+ * If the clause refers to different partition keys from
+ * both relations, it can not be used for partition-wise join.
+ */
+ if (ipk1 != ipk2)
+ continue;
+
+ /*
+ * The clause allows partition-wise join if only it uses the same
+ * operator family as that specified by the partition key.
+ */
+ if (!list_member_oid(rinfo->mergeopfamilies,
+ part_scheme->partopfamily[ipk1]))
+ continue;
+
+ /* Mark the partition key as having an equi-join clause. */
+ pk_has_clause[ipk1] = true;
+ }
+
+ /* Check whether every partition key has an equi-join condition. */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * Find the partition key from the given relation matching the given
+ * expression. If found, return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks;
+
+ /* This function should be called only for partitioned relations. */
+ Assert(rel->part_scheme);
+
+ num_pks = rel->part_scheme->partnatts;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() simplifies multiple
+ * RelabelType nodes into one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/path/pathkeys.c b/src/backend/optimizer/path/pathkeys.c
index 4436ac1..def64e3 100644
--- a/src/backend/optimizer/path/pathkeys.c
+++ b/src/backend/optimizer/path/pathkeys.c
@@ -1088,12 +1088,25 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
int necs;
ListCell *lc;
int j;
+ Relids relids;
/* Might have no mergeclauses */
if (nClauses == 0)
return NIL;
/*
+ * For a child join relation, use parent relids to find potential join
+ * partners (see code below) from equivalence classes. A potential join
+ * partner of parent also indicates potential join partner of the child. By
+ * using only parent relids, we avoid scoring an equivalence class multiple
+ * times once for parent and then for all of its children.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
+ /*
* Make arrays of the ECs used by the mergeclauses (dropping any
* duplicates) and their "popularity" scores.
*/
@@ -1133,7 +1146,7 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
/* Potential future join partner? */
if (!em->em_is_const && !em->em_is_child &&
- !bms_overlap(em->em_relids, joinrel->relids))
+ !bms_overlap(em->em_relids, relids))
score++;
}
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index ad49674..b754d90 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -30,6 +30,7 @@
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/paths.h"
+#include "optimizer/pathnode.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
#include "optimizer/planmain.h"
@@ -42,6 +43,7 @@
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
/*
@@ -145,6 +147,9 @@ static CustomScan *create_customscan_plan(PlannerInfo *root,
static NestLoop *create_nestloop_plan(PlannerInfo *root, NestPath *best_path);
static MergeJoin *create_mergejoin_plan(PlannerInfo *root, MergePath *best_path);
static HashJoin *create_hashjoin_plan(PlannerInfo *root, HashPath *best_path);
+static Plan *create_partition_plan(PlannerInfo *root, Path *best_path);
+static Plan *create_partition_join_plan(PlannerInfo *root,
+ PartitionJoinPath *best_path);
static Node *replace_nestloop_params(PlannerInfo *root, Node *expr);
static Node *replace_nestloop_params_mutator(Node *node, PlannerInfo *root);
static void process_subquery_nestloop_params(PlannerInfo *root,
@@ -241,7 +246,8 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
@@ -367,12 +373,8 @@ create_plan_recurse(PlannerInfo *root, Path *best_path, int flags)
(JoinPath *) best_path);
break;
case T_Append:
- plan = create_append_plan(root,
- (AppendPath *) best_path);
- break;
case T_MergeAppend:
- plan = create_merge_append_plan(root,
- (MergeAppendPath *) best_path);
+ plan = create_partition_plan(root, best_path);
break;
case T_Result:
if (IsA(best_path, ProjectionPath))
@@ -1115,6 +1117,30 @@ create_merge_append_plan(PlannerInfo *root, MergeAppendPath *best_path)
}
/*
+ * create_partition_plan
+ * Creates an Merge/Append plan as specified by the "best path".
+ *
+ * Returns a Plan node.
+ */
+static Plan *
+create_partition_plan(PlannerInfo *root, Path *best_path)
+{
+ Plan *plan;
+
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root, (PartitionJoinPath *)best_path);
+ else if (best_path->pathtype == T_Append)
+ plan = create_append_plan(root, (AppendPath *) best_path);
+ else
+ {
+ Assert(best_path->pathtype == T_MergeAppend);
+ plan = create_merge_append_plan(root, (MergeAppendPath *) best_path);
+ }
+
+ return plan;
+}
+
+/*
* create_result_plan
* Create a Result plan for 'best_path'.
* This is only used for degenerate cases, such as a query with an empty
@@ -1513,7 +1539,7 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
@@ -3530,6 +3556,8 @@ create_mergejoin_plan(PlannerInfo *root,
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
@@ -3537,10 +3565,10 @@ create_mergejoin_plan(PlannerInfo *root,
* best to request a small tlist so we aren't sorting more data than
* necessary.
*/
- outer_plan = create_plan_recurse(root, best_path->jpath.outerjoinpath,
+ outer_plan = create_plan_recurse(root, outer_path,
(best_path->outersortkeys != NIL) ? CP_SMALL_TLIST : 0);
- inner_plan = create_plan_recurse(root, best_path->jpath.innerjoinpath,
+ inner_plan = create_plan_recurse(root, inner_path,
(best_path->innersortkeys != NIL) ? CP_SMALL_TLIST : 0);
/* Sort join qual clauses into best execution order */
@@ -3586,34 +3614,38 @@ create_mergejoin_plan(PlannerInfo *root,
* outer_is_left status.
*/
mergeclauses = get_switched_clauses(best_path->path_mergeclauses,
- best_path->jpath.outerjoinpath->parent->relids);
+ outer_path->parent->relids);
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
outerpathkeys = best_path->outersortkeys;
}
else
- outerpathkeys = best_path->jpath.outerjoinpath->pathkeys;
+ outerpathkeys = outer_path->pathkeys;
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
innerpathkeys = best_path->innersortkeys;
}
else
- innerpathkeys = best_path->jpath.innerjoinpath->pathkeys;
+ innerpathkeys = inner_path->pathkeys;
/*
* If specified, add a materialize node to shield the inner plan from the
@@ -3951,6 +3983,212 @@ create_hashjoin_plan(PlannerInfo *root,
return join_plan;
}
+/*
+ * create_partition_join_plan
+ * Creates Merge/Append plan consisting of join plans for child-join.
+ *
+ * Returns a Plan node.
+ */
+static Plan *
+create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
+{
+ RelOptInfo *joinrel = best_path->path.parent;
+ int nparts;
+ int cnt_parts;
+ List *child_plans = NIL;
+ List *tlist = build_path_tlist(root, &best_path->path);
+ Plan *plan;
+ MemoryContext child_context;
+ MemoryContext old_context;
+ List *pathkeys = best_path->path.pathkeys;
+ StringInfoData mem_context_name;
+
+ /* The relation should be a partitioned join relation. */
+ Assert(IS_JOIN_REL(joinrel) && joinrel->part_scheme &&
+ joinrel->partitioned_joins);
+
+ nparts = joinrel->part_scheme->nparts;
+
+ /* Create MergeAppend plan when result is expected to be ordered. */
+ if (pathkeys)
+ {
+ MergeAppend *node = makeNode(MergeAppend);
+ plan = &node->plan;
+
+ plan->targetlist = tlist;
+
+ /* Compute sorting info, and adjust MergeAppend's tlist as needed. */
+ (void) prepare_sort_from_pathkeys(plan, pathkeys,
+ best_path->path.parent->relids,
+ NULL,
+ true,
+ &node->numCols,
+ &node->sortColIdx,
+ &node->sortOperators,
+ &node->collations,
+ &node->nullsFirst);
+ }
+ else
+ {
+ Append *node = makeNode(Append);
+ plan = &node->plan;
+ plan->targetlist = tlist;
+ }
+
+ /* Fill costs, so that we can cost Sort node, if required. */
+ copy_generic_path_info(plan, (Path *) best_path);
+
+ /*
+ * Create a new memory context for planning child joins. Since this routine
+ * may be called recursively for tables with subpartitions, we use
+ * a unique context name for every level of partition by using the lowest
+ * relid amongst the base relations being joined.
+ */
+ initStringInfo(&mem_context_name);
+ appendStringInfo(&mem_context_name, "%s_%d", "ChildJoinContext",
+ bms_next_member(joinrel->relids, -1));
+ child_context = AllocSetContextCreate(CurrentMemoryContext,
+ pstrdup(mem_context_name.data),
+ ALLOCSET_DEFAULT_SIZES);
+ pfree(mem_context_name.data);
+ resetStringInfo(&mem_context_name);
+
+ /*
+ * Create a paths for all child joins, one child join at a time. The paths
+ * for every child join are independent i.e. one child does not require
+ * paths created for the other. In order to avoid accumulating memory
+ * consumed while creating paths for every child join, we use a fresh
+ * memory context for every child join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_join;
+ Path *child_path;
+ Plan *child_plan;
+ int numsortkeys;
+ AttrNumber *sortColIdx;
+ Oid *sortOperators;
+ Oid *collations;
+ bool *nullsFirst;
+
+ /*
+ * Create paths for the child join in a separate context, so that we
+ * can reuse the memory used by those paths.
+ */
+ old_context = MemoryContextSwitchTo(child_context);
+
+ add_paths_to_child_joinrel(root, joinrel, cnt_parts);
+
+ MemoryContextSwitchTo(old_context);
+
+ child_join = joinrel->part_rels[cnt_parts];
+
+
+ /* Skip empty child. */
+ if (IS_DUMMY_REL(child_join))
+ continue;
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ /*
+ * Search for a child path with pathkeys or parameterization
+ * matching that of the given path.
+ */
+ child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
+ best_path->path.pathkeys,
+ PATH_REQ_OUTER(&best_path->path),
+ TOTAL_COST);
+
+ if (!child_path)
+ elog(ERROR, "Could not find a path with required pathkeys.");
+
+ /* Create plan for the current child. */
+ child_plan = create_plan_recurse(root, child_path, CP_EXACT_TLIST);
+
+ if (pathkeys)
+ {
+ MergeAppend *node = (MergeAppend *) plan;
+
+ Assert(IsA(node, MergeAppend));
+
+ /* Compute sorting info, and adjust subplan's tlist as needed */
+ child_plan = prepare_sort_from_pathkeys(child_plan, pathkeys,
+ child_path->parent->relids,
+ node->sortColIdx,
+ false,
+ &numsortkeys,
+ &sortColIdx,
+ &sortOperators,
+ &collations,
+ &nullsFirst);
+
+ /*
+ * Check that we got the same sort key information. We just Assert
+ * that the sortops match, since those depend only on the pathkeys;
+ * but it seems like a good idea to check the sort column numbers
+ * explicitly, to ensure the tlists really do match up.
+ */
+ Assert(numsortkeys == node->numCols);
+ if (memcmp(sortColIdx, node->sortColIdx,
+ numsortkeys * sizeof(AttrNumber)) != 0)
+ elog(ERROR, "MergeAppend child's targetlist doesn't match MergeAppend");
+ Assert(memcmp(sortOperators, node->sortOperators,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(collations, node->collations,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(nullsFirst, node->nullsFirst,
+ numsortkeys * sizeof(bool)) == 0);
+
+ /* Now, insert a Sort node if subplan isn't sufficiently ordered */
+ if (!pathkeys_contained_in(pathkeys, child_path->pathkeys))
+ {
+ Sort *sort = make_sort(child_plan, numsortkeys,
+ sortColIdx, sortOperators,
+ collations, nullsFirst);
+ label_sort_with_costsize(root, sort, -1.0);
+ child_plan = (Plan *) sort;
+ }
+ }
+
+ child_plans = lappend(child_plans, child_plan);
+
+ /*
+ * Reset the child_join memory context to reclaim the memory consumed
+ * while creating paths.
+ */
+ MemoryContextResetAndDeleteChildren(child_context);
+ }
+
+ /* Destroy the child context as we do not need it anymore. */
+ Assert(CurrentMemoryContext == old_context);
+ MemoryContextDelete(child_context);
+
+ /* Partitioned relation with all empty children gets a dummy path. */
+ Assert(child_plans != NIL);
+
+ if (IsA(plan, MergeAppend))
+ {
+ MergeAppend *node = (MergeAppend *)plan;
+
+ node->mergeplans = child_plans;
+ }
+ else
+ {
+ Append *node = (Append *)plan;
+
+ Assert(IsA(plan, Append));
+ node->appendplans = child_plans;
+ }
+
+ /* Complete rest of the plan. */
+ plan->qual = NIL;
+ plan->lefttree = NULL;
+ plan->righttree = NULL;
+ return plan;
+}
+
/*****************************************************************************
*
@@ -4009,6 +4247,7 @@ replace_nestloop_params_mutator(Node *node, PlannerInfo *root)
nlp->paramno = param->paramid;
nlp->paramval = var;
root->curOuterParams = lappend(root->curOuterParams, nlp);
+
/* And return the replacement Param */
return (Node *) param;
}
@@ -4072,6 +4311,7 @@ replace_nestloop_params_mutator(Node *node, PlannerInfo *root)
nlp->paramno = param->paramid;
nlp->paramval = (Var *) phv;
root->curOuterParams = lappend(root->curOuterParams, nlp);
+
/* And return the replacement Param */
return (Node *) param;
}
@@ -5343,11 +5583,11 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
@@ -5458,10 +5698,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
@@ -5482,9 +5722,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
@@ -5494,7 +5735,7 @@ make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 41dde50..fedbb43 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -1105,7 +1105,7 @@ inheritance_planner(PlannerInfo *root)
subroot->parse = (Query *)
adjust_appendrel_attrs(root,
(Node *) parse,
- appinfo);
+ list_make1(appinfo));
/*
* The rowMarks list might contain references to subquery RTEs, so
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index b714783..899e46f 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -55,7 +55,7 @@
typedef struct
{
PlannerInfo *root;
- AppendRelInfo *appinfo;
+ List *appinfos;
int sublevels_up;
} adjust_appendrel_attrs_context;
@@ -108,7 +108,6 @@ static Bitmapset *translate_col_privs(const Bitmapset *parent_privs,
List *translated_vars);
static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
-static Relids adjust_relid_set(Relids relids, Index oldrelid, Index newrelid);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
@@ -1712,10 +1711,10 @@ translate_col_privs(const Bitmapset *parent_privs,
/*
* adjust_appendrel_attrs
- * Copy the specified query or expression and translate Vars referring
- * to the parent rel of the specified AppendRelInfo to refer to the
- * child rel instead. We also update rtindexes appearing outside Vars,
- * such as resultRelation and jointree relids.
+ * Copy the specified query or expression and translate Vars referring to
+ * the parent rels specified in the given list of AppendRelInfos to refer to
+ * the corresponding child rels instead. We also update rtindexes appearing
+ * outside Vars, such as resultRelation and jointree relids.
*
* Note: this is applied after conversion of sublinks to subplans in the
* query jointree, but there may still be sublinks in the security barrier
@@ -1725,15 +1724,18 @@ translate_col_privs(const Bitmapset *parent_privs,
* maybe we should try to fold the two routines together.
*/
Node *
-adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
+adjust_appendrel_attrs(PlannerInfo *root, Node *node, List *appinfos)
{
Node *result;
adjust_appendrel_attrs_context context;
+ ListCell *lc;
context.root = root;
- context.appinfo = appinfo;
+ context.appinfos = appinfos;
context.sublevels_up = 0;
+ Assert(appinfos && list_length(appinfos) >= 1);
+
/*
* Must be prepared to start with a Query or a bare expression tree; if
* it's a Query, go straight to query_tree_walker to make sure that
@@ -1742,11 +1744,20 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
if (node && IsA(node, Query))
{
Query *newnode;
+ AppendRelInfo *appinfo;
newnode = query_tree_mutator((Query *) node,
adjust_appendrel_attrs_mutator,
(void *) &context,
QTW_IGNORE_RC_SUBQUERIES);
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (newnode->resultRelation == appinfo->parent_relid)
+ break;
+ }
+
if (newnode->resultRelation == appinfo->parent_relid)
{
newnode->resultRelation = appinfo->child_relid;
@@ -1764,17 +1775,51 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
return result;
}
+/*
+ * find_appinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *appinfo_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (bms_is_member(appinfo->child_relid, relids))
+ appinfo_list = lappend(appinfo_list, appinfo);
+ }
+
+ Assert(list_length(appinfo_list) == bms_num_members(relids));
+ return appinfo_list;
+}
+
static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
- AppendRelInfo *appinfo = context->appinfo;
+ List *appinfos = context->appinfos;
+ ListCell *lc;
+
+ Assert(appinfos && list_length(appinfos) >= 1);
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
Var *var = (Var *) copyObject(node);
+ AppendRelInfo *appinfo;
+
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (var->varno == appinfo->parent_relid)
+ break;
+ }
if (var->varlevelsup == context->sublevels_up &&
var->varno == appinfo->parent_relid)
@@ -1865,32 +1910,58 @@ adjust_appendrel_attrs_mutator(Node *node,
{
CurrentOfExpr *cexpr = (CurrentOfExpr *) copyObject(node);
- if (context->sublevels_up == 0 &&
- cexpr->cvarno == appinfo->parent_relid)
- cexpr->cvarno = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ cexpr->cvarno == appinfo->parent_relid)
+ {
+ cexpr->cvarno = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) cexpr;
}
if (IsA(node, RangeTblRef))
{
RangeTblRef *rtr = (RangeTblRef *) copyObject(node);
- if (context->sublevels_up == 0 &&
- rtr->rtindex == appinfo->parent_relid)
- rtr->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ rtr->rtindex == appinfo->parent_relid)
+ {
+ rtr->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) rtr;
}
if (IsA(node, JoinExpr))
{
/* Copy the JoinExpr node with correct mutation of subnodes */
JoinExpr *j;
+ AppendRelInfo *appinfo;
j = (JoinExpr *) expression_tree_mutator(node,
adjust_appendrel_attrs_mutator,
(void *) context);
+
/* now fix JoinExpr's rtindex (probably never happens) */
- if (context->sublevels_up == 0 &&
- j->rtindex == appinfo->parent_relid)
- j->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ j->rtindex == appinfo->parent_relid)
+ {
+ j->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) j;
}
if (IsA(node, PlaceHolderVar))
@@ -1903,9 +1974,8 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == context->sublevels_up)
- phv->phrels = adjust_relid_set(phv->phrels,
- appinfo->parent_relid,
- appinfo->child_relid);
+ phv->phrels = adjust_child_relids(phv->phrels, context->appinfos);
+
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1936,24 +2006,18 @@ adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_mutator((Node *) oldinfo->orclause, context);
/* adjust relid sets too */
- newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ newinfo->clause_relids = adjust_child_relids(oldinfo->clause_relids,
+ context->appinfos);
+ newinfo->required_relids = adjust_child_relids(oldinfo->required_relids,
+ context->appinfos);
+ newinfo->outer_relids = adjust_child_relids(oldinfo->outer_relids,
+ context->appinfos);
+ newinfo->nullable_relids = adjust_child_relids(oldinfo->nullable_relids,
+ context->appinfos);
+ newinfo->left_relids = adjust_child_relids(oldinfo->left_relids,
+ context->appinfos);
+ newinfo->right_relids = adjust_child_relids(oldinfo->right_relids,
+ context->appinfos);
/*
* Reset cached derivative fields, since these might need to have
@@ -2002,23 +2066,6 @@ adjust_appendrel_attrs_mutator(Node *node,
}
/*
- * Substitute newrelid for oldrelid in a Relid set
- */
-static Relids
-adjust_relid_set(Relids relids, Index oldrelid, Index newrelid)
-{
- if (bms_is_member(oldrelid, relids))
- {
- /* Ensure we have a modifiable copy */
- relids = bms_copy(relids);
- /* Remove old, add new */
- relids = bms_del_member(relids, oldrelid);
- relids = bms_add_member(relids, newrelid);
- }
- return relids;
-}
-
-/*
* Adjust the targetlist entries of an inherited UPDATE operation
*
* The expressions have already been fixed, but we have to make sure that
@@ -2135,5 +2182,91 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
else
Assert(parent_rel->reloptkind == RELOPT_BASEREL);
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, appinfo);
+ return adjust_appendrel_attrs(root, node, list_make1(appinfo));
+}
+
+/*
+ * build_child_restrictinfo
+ * Returns a RestrictInfo which is derived from the given RestrictInfo by
+ * applying the parent-child translation specified by the list of
+ * AppendRelInfos.
+ *
+ * The topmost parent's RestrictInfo maintains a list of child RestrictInfos
+ * derived from it. If a suitable RestrictInfo is found in that list, it is
+ * returned as is. If there is no such child RestrictInfo, we translate the given
+ * RestrictInfo using the given list of AppendRelInfos and stick it in the
+ * topmost parent's list before returning it to the caller.
+ */
+RestrictInfo *
+build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
+ List *append_rel_infos)
+{
+ Relids child_required_relids;
+ ListCell *lc;
+ RestrictInfo *parent_rinfo;
+ RestrictInfo *child_rinfo;
+ MemoryContext old_context;
+
+ child_required_relids = adjust_child_relids(rinfo->required_relids,
+ append_rel_infos);
+ /*
+ * Check if we already have the RestrictInfo for the given child in the
+ * topmost parent's RestrictInfo.
+ */
+ parent_rinfo = rinfo->parent_rinfo ? rinfo->parent_rinfo : rinfo;
+ foreach (lc, parent_rinfo->child_rinfos)
+ {
+ child_rinfo = lfirst(lc);
+
+ if (bms_equal(child_rinfo->required_relids, child_required_relids))
+ {
+ bms_free(child_required_relids);
+ return child_rinfo;
+ }
+ }
+
+ /*
+ * We didn't find any child restrictinfo for the given child, translate the
+ * given RestrictInfo and stick it into the parent's list. The clause
+ * expression may get used in plan, so create the child RestrictInfo in the
+ * planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ child_rinfo = (RestrictInfo *) adjust_appendrel_attrs(root, (Node *) rinfo,
+ append_rel_infos);
+ bms_free(child_required_relids);
+ parent_rinfo->child_rinfos = lappend(parent_rinfo->child_rinfos,
+ child_rinfo);
+ child_rinfo->parent_rinfo = parent_rinfo;
+
+ MemoryContextSwitchTo(old_context);
+
+ return child_rinfo;
+}
+
+/*
+ * build_child_clauses
+ * Convenience routine to call build_child_restrictinfo on a list of
+ * clauses.
+ */
+List *
+build_child_clauses(PlannerInfo *root, List *clauses, List *append_rel_infos)
+{
+ List *child_clauses = NIL;
+ ListCell *lc;
+
+ foreach (lc, clauses)
+ {
+ RestrictInfo *parent_rinfo = lfirst(lc);
+ RestrictInfo *child_rinfo;
+
+ Assert(IsA(parent_rinfo, RestrictInfo));
+
+ child_rinfo = build_child_restrictinfo(root, parent_rinfo,
+ append_rel_infos);
+
+ child_clauses = lappend(child_clauses, child_rinfo);
+ }
+
+ return child_clauses;
}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index 6d3ccfd..37e5f38 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -23,7 +23,9 @@
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
@@ -2154,6 +2156,176 @@ create_hashjoin_path(PlannerInfo *root,
}
/*
+ * create_partition_join_path
+ * Creates a pathnode that represents partition-wise join for given
+ * partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the cost of representative child-joins
+ * paths.
+ */
+PartitionJoinPath *
+create_partition_join_path(RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = T_Append;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = NULL;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+ subpath_total_cost += subpath->total_cost;
+
+ /*
+ * Startup cost of an append relation is the startup cost of the first
+ * subpath. Assume that the given first child will be the first child
+ * in the final plan as well.
+ */
+ if (lc == list_head(subpaths))
+ subpath_startup_cost = subpath->startup_cost;
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ pathnode->path.startup_cost = subpath_startup_cost;
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ /*
+ * Multiply the costs with scaling factor as specified. Used to encourage
+ * or discourage use of partition-wise join plans.
+ */
+ pathnode->path.startup_cost *= partition_wise_plan_weight;
+ pathnode->path.total_cost *= partition_wise_plan_weight;
+
+ return pathnode;
+}
+
+/*
+ * create_partition_join_path_with_pathkeys
+ * Creates a pathnode that represents an ordered partition-wise join for
+ * given partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the cost of representative child-joins
+ * paths.
+ */
+PartitionJoinPath *
+create_partition_join_path_with_pathkeys(PlannerInfo *root, RelOptInfo *rel,
+ List *subpaths, List *pathkeys,
+ Bitmapset *required_outer)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = T_MergeAppend;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = pathkeys;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ if (pathkeys_contained_in(pathkeys, subpath->pathkeys))
+ {
+ /* Subpath is adequately ordered, we won't need to sort it */
+ subpath_startup_cost += subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else
+ {
+ /* We'll need to insert a Sort node, so include cost for that */
+ Path sort_path; /* dummy for result of cost_sort */
+
+ cost_sort(&sort_path,
+ root,
+ pathkeys,
+ subpath->total_cost,
+ subpath->parent->tuples,
+ subpath->pathtarget->width,
+ 0.0,
+ work_mem,
+ -1);
+ subpath_startup_cost += sort_path.startup_cost;
+ subpath_total_cost += sort_path.total_cost;
+ }
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ pathnode->path.startup_cost = (subpath_startup_cost * pathnode->path.rows) / subpath_rows;
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ /*
+ * Multiply the costs with scaling factor as specified. Used to encourage
+ * or discourage use of partition-wise join plans.
+ */
+ pathnode->path.startup_cost *= partition_wise_plan_weight;
+ pathnode->path.total_cost *= partition_wise_plan_weight;
+
+ return pathnode;
+}
+/*
* create_projection_path
* Creates a pathnode that represents performing a projection.
*
@@ -3209,3 +3381,182 @@ reparameterize_path(PlannerInfo *root, Path *path,
}
return NULL;
}
+
+/*
+ * reparameterize_path_by_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ *
+ * The cost, number of rows, width and parallel path properties depend upon
+ * path->parent, which does not change during the translation. Hence those
+ * members are copied as they are.
+ */
+
+Path *
+reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+ Relids required_outer;
+
+ /*
+ * If the path is not parameterized by parent of the given relation or it it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ required_outer = adjust_child_relids(old_ppi->ppi_req_outer, child_aris);
+
+ /* If we already have a PPI for this parameterization, just return it */
+ new_ppi = find_param_path_info(new_path->parent, required_outer);
+
+ /* If not build a new one and link it to the list of PPIs. */
+ if (!new_ppi)
+ {
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = required_outer;
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = build_child_clauses(root, old_ppi->ppi_clauses,
+ child_aris);
+ new_path->param_info = new_ppi;
+ new_path->parent->ppilist = lappend(new_path->parent->ppilist, new_ppi);
+ }
+ else
+ bms_free(required_outer);
+
+ /*
+ * Adjust the path target if the parent of the outer relation is referenced
+ * in the targetlist. This can happen when only the parent of outer relation is
+ * laterally referenced in this relation.
+ */
+ if (bms_overlap(path->parent->lateral_relids, child_rel->top_parent_relids))
+ {
+ MemoryContext old_context;
+
+ /*
+ * Allocate the target in planner's context, since they are copies as
+ * is from path while creating plans.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ MemoryContextSwitchTo(old_context);
+ }
+
+ /*
+ * Change parameterization of subpaths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_by_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_by_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = build_child_clauses(root,
+ jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_by_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexclauses = build_child_clauses(root, ipath->indexclauses,
+ child_aris);
+ ipath->indexquals = build_child_clauses(root, ipath->indexquals,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/placeholder.c b/src/backend/optimizer/util/placeholder.c
index b210914..859e6a6 100644
--- a/src/backend/optimizer/util/placeholder.c
+++ b/src/backend/optimizer/util/placeholder.c
@@ -21,6 +21,7 @@
#include "optimizer/placeholder.h"
#include "optimizer/planmain.h"
#include "optimizer/var.h"
+#include "optimizer/prep.h"
#include "utils/lsyscache.h"
/* Local functions */
@@ -411,9 +412,15 @@ void
add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *lc;
+ /* PlaceHolderInfo refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(lc, root->placeholder_list)
{
PlaceHolderInfo *phinfo = (PlaceHolderInfo *) lfirst(lc);
@@ -424,9 +431,27 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
/* Is it computable here? */
if (bms_is_subset(phinfo->ph_eval_at, relids))
{
+ PlaceHolderVar *phv = phinfo->ph_var;
+
+ /*
+ * In case the placeholder Var refers to any of the parent
+ * relation, translate it to refer to the corresponding child.
+ */
+ if (bms_overlap(phv->phrels, relids) &&
+ joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ {
+ List *append_rel_infos;
+
+ append_rel_infos = find_appinfos_by_relids(root,
+ joinrel->relids);
+ phv = (PlaceHolderVar *) adjust_appendrel_attrs(root,
+ (Node *) phv,
+ append_rel_infos);
+ }
+
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs,
- phinfo->ph_var);
+ phv);
joinrel->reltarget->width += phinfo->ph_width;
/*
@@ -445,7 +470,7 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
{
QualCost cost;
- cost_qual_eval_node(&cost, (Node *) phinfo->ph_var->phexpr,
+ cost_qual_eval_node(&cost, (Node *) phv->phexpr,
root);
joinrel->reltarget->cost.startup += cost.startup;
joinrel->reltarget->cost.per_tuple += cost.per_tuple;
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 72272d9..88e66e4 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -412,6 +412,21 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation, inhparent);
+ /*
+ * Lookup partition scheme for the given relation. Only parent relations
+ * can be partitioned.
+ */
+ if (inhparent)
+ rel->part_scheme = find_partition_scheme(root, relation);
+ else
+ rel->part_scheme = NULL;
+
+ if (rel->part_scheme)
+ rel->partexprs = build_baserel_partition_key_exprs(relation,
+ rel->relid);
+ else
+ rel->partexprs = NULL;
+
heap_close(relation, NoLock);
/*
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index d5326e6..d1433ec 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -15,15 +15,22 @@
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
+#include "catalog/partition.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
+#include "nodes/makefuncs.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "optimizer/var.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
@@ -34,10 +41,6 @@ typedef struct JoinHashEntry
static void build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel);
-static List *build_joinrel_restrictlist(PlannerInfo *root,
- RelOptInfo *joinrel,
- RelOptInfo *outer_rel,
- RelOptInfo *inner_rel);
static void build_joinrel_joinlist(RelOptInfo *joinrel,
RelOptInfo *outer_rel,
RelOptInfo *inner_rel);
@@ -47,6 +50,20 @@ static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
+static void build_child_joinrel_joinlist(PlannerInfo *root,
+ RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel);
+static List *subbuild_child_joinrel_joinlist(PlannerInfo *root,
+ RelOptInfo *joinrel, List *joininfo_list,
+ RelOptInfo *other_rel, List *new_joininfo);
+static List *subbuild_child_joinrel_restrictlist(PlannerInfo *root,
+ RelOptInfo *joinrel, List *joininfo_list,
+ RelOptInfo *other_rel, List *new_restrictlist);
/*
@@ -137,6 +154,10 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
rel->baserestrictcost.per_tuple = 0;
rel->joininfo = NIL;
rel->has_eclass_joins = false;
+ rel->part_scheme = NULL;
+ rel->partexprs = NULL;
+ rel->top_parent_relids = NULL;
+ rel->part_rels = NULL;
/* Check type of rtable entry */
switch (rte->rtekind)
@@ -314,6 +335,56 @@ find_join_rel(PlannerInfo *root, Relids relids)
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
@@ -363,7 +434,11 @@ build_join_rel(PlannerInfo *root,
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
+
+ Assert(!IS_OTHER_REL(outer_rel) && !IS_OTHER_REL(inner_rel));
+
joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
@@ -409,47 +484,13 @@ build_join_rel(PlannerInfo *root,
joinrel->baserestrictcost.per_tuple = 0;
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Compute information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
@@ -475,6 +516,10 @@ build_join_rel(PlannerInfo *root,
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
@@ -517,25 +562,8 @@ build_join_rel(PlannerInfo *root,
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the query's PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
@@ -555,6 +583,125 @@ build_join_rel(PlannerInfo *root,
}
/*
+ * build_child_join_rel
+ * Builds RelOptInfo for joining given two child relations from RelOptInfo
+ * representing the join between their parents.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of child relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for child join
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_appinfos': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ JoinType jointype)
+{
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel) && IS_OTHER_REL(inner_rel));
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Compute information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /* Build targetlist */
+ build_joinrel_tlist(root, joinrel, outer_rel);
+ build_joinrel_tlist(root, joinrel, inner_rel);
+ /* Add placeholder variables. */
+ add_placeholders_to_joinrel(root, joinrel, outer_rel, inner_rel);
+
+ /* Construct joininfo list. */
+ build_child_joinrel_joinlist(root, joinrel, outer_rel, inner_rel);
+
+ /*
+ * Lateral relids referred in child join will be same as that referred in
+ * the parent relation. Throw any partial result computed while building
+ * the targetlist.
+ */
+ bms_free(joinrel->direct_lateral_relids);
+ bms_free(joinrel->lateral_relids);
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, jointype);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ /* We build the join only once. */
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
+/*
* min_join_parameterization
*
* Determine the minimum possible parameterization of a joinrel, that is, the
@@ -609,9 +756,15 @@ static void
build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *vars;
+ /* attrs_needed refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(vars, input_rel->reltarget->exprs)
{
Var *var = (Var *) lfirst(vars);
@@ -627,23 +780,47 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
/*
* Otherwise, anything in a baserel or joinrel targetlist ought to be
- * a Var. (More general cases can only appear in appendrel child
- * rels, which will never be seen here.)
+ * a Var or ConvertRowtypeExpr introduced while translating parent
+ * targetlist to that of the child.
*/
- if (!IsA(var, Var))
+ if (IsA(var, Var))
+ {
+ /* Get the Var's original base rel */
+ baserel = find_base_rel(root, var->varno);
+
+ /* Is it still needed above this joinrel? */
+ ndx = var->varattno - baserel->min_attr;
+ }
+ else if (IsA(var, ConvertRowtypeExpr))
+ {
+ ConvertRowtypeExpr *child_expr = (ConvertRowtypeExpr *) var;
+ Var *childvar = (Var *) child_expr->arg;
+
+ /*
+ * Child's whole-row references are converted to that of parent
+ * using ConvertRowtypeExpr. In this case, the argument to
+ * ConvertRowtypeExpr is expected to be a whole-row reference of
+ * the child.
+ */
+ Assert(IsA(childvar, Var) && childvar->varattno == 0);
+
+ baserel = find_base_rel(root, childvar->varno);
+ ndx = 0 - baserel->min_attr;
+ }
+ else
elog(ERROR, "unexpected node type in rel targetlist: %d",
(int) nodeTag(var));
- /* Get the Var's original base rel */
- baserel = find_base_rel(root, var->varno);
-
- /* Is it still needed above this joinrel? */
- ndx = var->varattno - baserel->min_attr;
if (bms_nonempty_difference(baserel->attr_needed[ndx], relids))
{
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs, var);
- /* Vars have cost zero, so no need to adjust reltarget->cost */
+
+ /*
+ * Vars have cost zero, so no need to adjust reltarget->cost. Even
+ * if, it's a ConvertRowtypeExpr, it will be computed only for the
+ * base relation, costing nothing for a join.
+ */
joinrel->reltarget->width += baserel->attr_widths[ndx];
}
}
@@ -691,7 +868,7 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
* RestrictInfo nodes are no longer context-dependent. Instead, just include
* the original nodes in the lists made for the join relation.
*/
-static List *
+List *
build_joinrel_restrictlist(PlannerInfo *root,
RelOptInfo *joinrel,
RelOptInfo *outer_rel,
@@ -780,6 +957,8 @@ subbuild_joinrel_joinlist(RelOptInfo *joinrel,
{
ListCell *l;
+ Assert(joinrel->reloptkind == RELOPT_JOINREL);
+
foreach(l, joininfo_list)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(l);
@@ -808,6 +987,154 @@ subbuild_joinrel_joinlist(RelOptInfo *joinrel,
return new_joininfo;
}
+/* Similar to build_joinrel_joinlist, but used for child-join relations. */
+static void
+build_child_joinrel_joinlist(PlannerInfo *root, RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel)
+{
+ List *result;
+
+ Assert(joinrel->reloptkind == RELOPT_OTHER_JOINREL);
+
+ result = subbuild_child_joinrel_joinlist(root, joinrel,
+ outer_rel->joininfo, inner_rel,
+ NIL);
+ result = subbuild_child_joinrel_joinlist(root, joinrel,
+ inner_rel->joininfo, outer_rel,
+ result);
+ joinrel->joininfo = result;
+}
+
+/* Similar to subbuild_joinrel_restrictlist(), but used for child-joins. */
+List *
+build_child_joinrel_restrictlist(PlannerInfo *root, RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel)
+{
+ List *result;
+
+ Assert(joinrel->reloptkind == RELOPT_OTHER_JOINREL);
+
+ result = subbuild_child_joinrel_restrictlist(root, joinrel,
+ outer_rel->joininfo,
+ inner_rel, NIL);
+ result = subbuild_child_joinrel_restrictlist(root, joinrel,
+ inner_rel->joininfo,
+ outer_rel, result);
+
+ /*
+ * Add on any clauses derived from EquivalenceClasses. These cannot be
+ * redundant with the clauses in the joininfo lists, so don't bother
+ * checking.
+ */
+ result = list_concat(result,
+ generate_join_implied_equalities(root,
+ joinrel->relids,
+ outer_rel->relids,
+ inner_rel));
+
+ return result;
+}
+
+/*
+ * Similar to subbuild_joinrel_joinlist() but used for child-joins.
+ */
+static List *
+subbuild_child_joinrel_joinlist(PlannerInfo *root, RelOptInfo *joinrel,
+ List *joininfo_list, RelOptInfo *other_rel,
+ List *new_joininfo)
+{
+ ListCell *l;
+ List *append_rel_infos = find_appinfos_by_relids(root,
+ other_rel->relids);
+
+ Assert(joinrel->reloptkind == RELOPT_OTHER_JOINREL);
+
+ foreach(l, joininfo_list)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *) lfirst(l);
+ RestrictInfo *parent_rinfo;
+
+ parent_rinfo = rinfo->parent_rinfo ? rinfo->parent_rinfo : rinfo;
+
+ if (bms_is_subset(parent_rinfo->required_relids, joinrel->top_parent_relids))
+ {
+ /*
+ * The child clause derived from this clause becomes a restriction
+ * clause for the joinrel, since it refers to no outside rels. So
+ * we can ignore it in this routine.
+ */
+ }
+ else
+ {
+ /*
+ * If the clause references parent of other joining relation, we
+ * need to translate those references to the child relation.
+ */
+ if (bms_overlap(rinfo->required_relids, other_rel->top_parent_relids))
+ rinfo = build_child_restrictinfo(root, rinfo, append_rel_infos);
+
+ /*
+ * This clause is still a join clause at this level, so add it to
+ * the new joininfo list, being careful to eliminate duplicates.
+ * (Since RestrictInfo nodes in different joinlists will have been
+ * multiply-linked rather than copied, pointer equality should be
+ * a sufficient test.)
+ */
+ new_joininfo = list_append_unique_ptr(new_joininfo, rinfo);
+ }
+ }
+
+ list_free(append_rel_infos);
+
+ return new_joininfo;
+}
+
+static List *
+subbuild_child_joinrel_restrictlist(PlannerInfo *root, RelOptInfo *joinrel,
+ List *joininfo_list, RelOptInfo *other_rel,
+ List *new_restrictlist)
+{
+ ListCell *l;
+ List *append_rel_infos = find_appinfos_by_relids(root,
+ other_rel->relids);
+
+ Assert(joinrel->reloptkind == RELOPT_OTHER_JOINREL);
+
+ foreach(l, joininfo_list)
+ {
+ RestrictInfo *rinfo = (RestrictInfo *) lfirst(l);
+ RestrictInfo *parent_rinfo;
+
+ parent_rinfo = rinfo->parent_rinfo ? rinfo->parent_rinfo : rinfo;
+
+ if (bms_is_subset(parent_rinfo->required_relids, joinrel->top_parent_relids))
+ {
+ /*
+ * The child clause derived from this clause becomes a restriction
+ * clause for the joinrel, since it refers to no outside rels. Add
+ * it to the list, being careful to eliminate duplicates. (Since
+ * RestrictInfo nodes in different joinlists will have been
+ * multiply-linked rather than copied, pointer equality should be a
+ * sufficient test.)
+ */
+ Assert(bms_overlap(rinfo->required_relids,
+ other_rel->top_parent_relids));
+
+ rinfo = build_child_restrictinfo(root, rinfo, append_rel_infos);
+ new_restrictlist = list_append_unique_ptr(new_restrictlist, rinfo);
+ }
+ else
+ {
+ /*
+ * This clause is still a join clause at this level, so we ignore
+ * it in this routine.
+ */
+ }
+ }
+
+ return new_restrictlist;
+}
+
/*
* build_empty_join_rel
@@ -933,9 +1260,17 @@ find_childrel_appendrelinfo(PlannerInfo *root, RelOptInfo *rel)
* appendrel ancestors. This function locates the topmost ancestor,
* which will be a regular baserel not an otherrel.
*/
-RelOptInfo *
+Relids
find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel)
{
+ Assert(IS_OTHER_REL(rel));
+
+ /* Child-join relations cache this in their RelOptInfo. */
+ if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ return rel->top_parent_relids;
+
+ Assert(rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
do
{
AppendRelInfo *appinfo = find_childrel_appendrelinfo(root, rel);
@@ -947,7 +1282,7 @@ find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel)
Assert(rel->reloptkind == RELOPT_BASEREL);
- return rel;
+ return rel->relids;
}
@@ -1009,12 +1344,8 @@ get_baserel_parampathinfo(PlannerInfo *root, RelOptInfo *baserel,
Assert(!bms_overlap(baserel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, baserel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(baserel, required_outer)))
+ return ppi;
/*
* Identify all joinclauses that are movable to this base rel given this
@@ -1251,12 +1582,8 @@ get_joinrel_parampathinfo(PlannerInfo *root, RelOptInfo *joinrel,
*restrict_clauses = list_concat(pclauses, *restrict_clauses);
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, joinrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(joinrel, required_outer)))
+ return ppi;
/* Estimate the number of rows returned by the parameterized join */
rows = get_parameterized_joinrel_size(root, joinrel,
@@ -1295,7 +1622,6 @@ ParamPathInfo *
get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
{
ParamPathInfo *ppi;
- ListCell *lc;
/* Unparameterized paths have no ParamPathInfo */
if (bms_is_empty(required_outer))
@@ -1304,12 +1630,8 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
Assert(!bms_overlap(appendrel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, appendrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(appendrel, required_outer)))
+ return ppi;
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
@@ -1320,3 +1642,130 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
return ppi;
}
+
+/*
+ * add_join_rel
+ * Add given join relation to the list of join relations in the given
+ * PlannerInfo. Also add it to the auxiliary hashtable if there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
+ * build_joinrel_partition_info
+ * If the join between given partitioned relations is possibly partitioned
+ * set the partitioning scheme and partition keys expressions for the
+ * join.
+ *
+ * If the two relations have same partitioning scheme, their join may be
+ * partitioned and will follow the same partitioning scheme as the joining
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /* Nothing to do if partition-wise join technique is disabled. */
+ if (!enable_partition_wise_join)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * The join is not partitioned, if any of the relations being joined are
+ * not partitioned or they do not have same partitioning scheme.
+ */
+ if (!outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel, hence it should
+ * not have partition scheme, partition key expressions and array for
+ * storing child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ /*
+ * Join relation is partitioned using same partitioning scheme as the
+ * joining relations.
+ */
+ joinrel->part_scheme = outer_rel->part_scheme;
+ num_pks = joinrel->part_scheme->partnatts;
+
+ /*
+ * Construct partition keys for the join.
+ *
+ * An INNER join between two partitioned relations is partition by key
+ * expressions from both the relations. For tables A and B partitioned by a and b
+ * respectively, (A INNER JOIN B ON A.a = B.b) is partitioned by both A.a
+ * and B.b.
+ *
+ * An OUTER join like (A LEFT JOIN B ON A.a = B.b) may produce rows with
+ * B.b NULL. These rows may not fit the partitioning conditions imposed on
+ * B.b. Hence, strictly speaking, the join is not partitioned by B.b.
+ * Strictly speaking, partition keys of an OUTER join should include
+ * partition key expressions from the OUTER side only. Consider a join like
+ * (A LEFT JOIN B on (A.a = B.b) LEFT JOIN C ON B.b = C.c. If we do not
+ * include B.b as partition key expression for (AB), it prohibits us from
+ * using partition-wise join when joining (AB) with C as there is no
+ * equi-join between partition keys of joining relations. But two NULL
+ * values are never equal and no two rows from mis-matching partitions can
+ * join. Hence it's safe to include B.b as partition key expression for
+ * (AB), even though rows in (AB) are not strictly partitioned by B.b.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
+
+/*
+ * Returns a ParamPathInfo for outer relations specified by required_outer, if
+ * already available in the given rel. Returns NULL otherwise.
+ */
+ParamPathInfo *
+find_param_path_info(RelOptInfo *rel, Relids required_outer)
+{
+ ListCell *lc;
+
+ foreach(lc, rel->ppilist)
+ {
+ ParamPathInfo *ppi = (ParamPathInfo *) lfirst(lc);
+ if (bms_equal(ppi->ppi_req_outer, required_outer))
+ return ppi;
+ }
+
+ return NULL;
+}
diff --git a/src/backend/postmaster/startup.c b/src/backend/postmaster/startup.c
index a7ae7e3..6787df6 100644
--- a/src/backend/postmaster/startup.c
+++ b/src/backend/postmaster/startup.c
@@ -169,7 +169,6 @@ HandleStartupProcInterrupts(void)
exit(1);
}
-
/* ----------------------------------
* Startup Process main entry point
* ----------------------------------
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 4973396..713e361 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3426,7 +3426,9 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
if (rel->tuples > 0)
{
/*
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index a025117..ee0c4f9 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -894,6 +894,15 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
@@ -2937,6 +2946,16 @@ static struct config_real ConfigureNamesReal[] =
},
{
+ {"partition_wise_plan_weight", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Multiplication factor for partition-wise plan costs."),
+ NULL
+ },
+ &partition_wise_plan_weight,
+ DEFAULT_PARTITION_WISE_PLAN_WEIGHT, 0, DBL_MAX,
+ NULL, NULL, NULL
+ },
+
+ {
{"bgwriter_lru_multiplier", PGC_SIGHUP, RESOURCES_BGWRITER,
gettext_noop("Multiple of the average buffer usage to free per round."),
NULL
diff --git a/src/include/catalog/partition.h b/src/include/catalog/partition.h
index 21effbf..e174923 100644
--- a/src/include/catalog/partition.h
+++ b/src/include/catalog/partition.h
@@ -63,6 +63,42 @@ typedef struct PartitionDispatchData
typedef struct PartitionDispatchData *PartitionDispatch;
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting may be partitioned in the same way as the underlying
+ * scan relations. All such relations partitioned in the same way share the
+ * partitioning scheme.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ PartitionBoundInfo boundinfo; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
+typedef struct PartitionSchemeData *PartitionScheme;
+
+/* Include here to avoid circular dependency with relation.h. */
+struct PlannerInfo;
+
extern void RelationBuildPartitionDesc(Relation relation);
extern bool partition_bounds_equal(PartitionKey key,
PartitionBoundInfo p1, PartitionBoundInfo p2);
@@ -80,4 +116,9 @@ extern int get_partition_for_tuple(PartitionDispatch *pd,
TupleTableSlot *slot,
EState *estate,
Oid *failed_at);
+extern List **build_baserel_partition_key_exprs(Relation relation,
+ Index varno);
+extern PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+
#endif /* PARTITION_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index c514d3f..297ec92 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -238,6 +238,7 @@ typedef enum NodeTag
T_NestPath,
T_MergePath,
T_HashPath,
+ T_PartitionJoinPath,
T_AppendPath,
T_MergeAppendPath,
T_ResultPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 3a1255a..0a7f21a 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -15,6 +15,7 @@
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
@@ -263,6 +264,9 @@ typedef struct PlannerInfo
List *initial_rels; /* RelOptInfos we are now trying to join */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
/* Use fetch_upper_rel() to get any particular upper rel */
List *upper_rels[UPPERREL_FINAL + 1]; /* upper-rel RelOptInfos */
@@ -352,6 +356,11 @@ typedef struct PlannerInfo
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing joins between child relations of
+ * different partitioned tables. These relations are not added to
+ * join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
@@ -471,10 +480,19 @@ typedef enum RelOptKind
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(rel) \
+ ((rel)->reloptkind == RELOPT_OTHER_MEMBER_REL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
+#define IS_JOIN_REL(rel) \
+ ((rel)->reloptkind == RELOPT_JOINREL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
@@ -542,6 +560,27 @@ typedef struct RelOptInfo
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there may be as many elements
+ * as the number of joining
+ * relations.
+ */
+ List *partitioned_joins; /* List of join orders which yield
+ * relations partitioned by above
+ * partition scheme.
+ */
+
+ /* Set only for "other" base or join relations. */
+ Relids top_parent_relids; /* Relids of topmost parents. */
} RelOptInfo;
/*
@@ -1469,6 +1508,14 @@ typedef struct LimitPath
Node *limitCount; /* COUNT parameter, or NULL if none */
} LimitPath;
+/*
+ * PartitionJoinPath represents partition-wise join between two partitioned
+ * tables.
+ */
+typedef struct PartitionJoinPath
+{
+ Path path;
+} PartitionJoinPath;
/*
* Restriction clause info.
@@ -1663,6 +1710,12 @@ typedef struct RestrictInfo
/* cache space for hashclause processing; -1 if not yet set */
Selectivity left_bucketsize; /* avg bucketsize of left side */
Selectivity right_bucketsize; /* avg bucketsize of right side */
+
+ /* Only one of these two can be set. */
+ List *child_rinfos; /* RestrictInfos derived for children. */
+ struct RestrictInfo *parent_rinfo; /* Parent restrictinfo this
+ * RestrictInf is derived from.
+ */
} RestrictInfo;
/*
@@ -1785,6 +1838,19 @@ typedef struct SpecialJoinInfo
} SpecialJoinInfo;
/*
+ * Partitioned join information
+ *
+ * Saves information about relations which can be joined partition-wise and
+ * thus produce result partitioned by the partition scheme of the relation.
+ */
+typedef struct PartitionedJoin
+{
+ RelOptInfo *rel1;
+ RelOptInfo *rel2;
+ SpecialJoinInfo *sjinfo;
+} PartitionedJoin;
+
+/*
* Append-relation info.
*
* When we expand an inheritable table or a UNION-ALL subselect into an
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..aff7ab7 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -30,6 +30,7 @@
#define DEFAULT_PARALLEL_SETUP_COST 1000.0
#define DEFAULT_EFFECTIVE_CACHE_SIZE 524288 /* measured in pages */
+#define DEFAULT_PARTITION_WISE_PLAN_WEIGHT 1
typedef enum
{
@@ -66,7 +67,9 @@ extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
+extern double partition_wise_plan_weight;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 71d9154..f36277f 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -225,10 +225,17 @@ extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
+extern PartitionJoinPath *create_partition_join_path(RelOptInfo *rel,
+ List *subpaths, Bitmapset *required_outer);
+extern PartitionJoinPath *create_partition_join_path_with_pathkeys(PlannerInfo *root,
+ RelOptInfo *rel, List *subpaths,
+ List *pathkeys, Bitmapset *required_outer);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
@@ -253,7 +260,7 @@ extern RelOptInfo *fetch_upper_rel(PlannerInfo *root, UpperRelationKind kind,
Relids relids);
extern AppendRelInfo *find_childrel_appendrelinfo(PlannerInfo *root,
RelOptInfo *rel);
-extern RelOptInfo *find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel);
+extern Relids find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel);
extern Relids find_childrel_parents(PlannerInfo *root, RelOptInfo *rel);
extern ParamPathInfo *get_baserel_parampathinfo(PlannerInfo *root,
RelOptInfo *baserel,
@@ -267,5 +274,18 @@ extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, JoinType jointype);
+extern List *build_joinrel_restrictlist(PlannerInfo *root,
+ RelOptInfo *joinrel,
+ RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel);
+extern void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
+extern List *build_child_joinrel_restrictlist(PlannerInfo *root,
+ RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..5d7bcd9 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -53,6 +53,8 @@ extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
extern void generate_gather_paths(PlannerInfo *root, RelOptInfo *rel);
+extern void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
#ifdef OPTIMIZER_DEBUG
extern void debug_print_rel(PlannerInfo *root, RelOptInfo *rel);
@@ -104,6 +106,9 @@ extern bool have_join_order_restriction(PlannerInfo *root,
RelOptInfo *rel1, RelOptInfo *rel2);
extern bool have_dangerous_phv(PlannerInfo *root,
Relids outer_relids, Relids inner_params);
+extern void add_paths_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *parent_joinrel,
+ int child_id);
/*
* equivclass.c
@@ -219,4 +224,6 @@ extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
+
#endif /* PATHS_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index fb35b68..2483303 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -28,6 +28,9 @@ extern void flatten_simple_union_all(PlannerInfo *root);
extern void reduce_outer_joins(PlannerInfo *root);
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
+extern Node *adjust_join_appendrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos);
+extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
/*
* prototypes for prepqual.c
@@ -58,9 +61,13 @@ extern RelOptInfo *plan_set_operations(PlannerInfo *root);
extern void expand_inherited_tables(PlannerInfo *root);
extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
- AppendRelInfo *appinfo);
+ List *appinfos);
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
+extern RestrictInfo *build_child_restrictinfo(PlannerInfo *root,
+ RestrictInfo *rinfo, List *append_rel_infos);
+extern List *build_child_clauses(PlannerInfo *root, List *clauses,
+ List *append_rel_infos);
#endif /* PREP_H */
diff --git a/src/test/regress/expected/multi_level_partition_join.out b/src/test/regress/expected/multi_level_partition_join.out
new file mode 100644
index 0000000..d40ae55
--- /dev/null
+++ b/src/test/regress/expected/multi_level_partition_join.out
@@ -0,0 +1,458 @@
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.b = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text) AND ((t1_1.b + t1_1.a) = (t2_1.a + t2_1.b)))
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.b = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text) AND ((t1_2.b + t1_2.a) = (t2_2.a + t2_2.b)))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
+ Hash Cond: ((t1_3.a = t2_3.b) AND (t1_3.b = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text) AND ((t1_3.b + t1_3.a) = (t2_3.a + t2_3.b)))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Hash
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: ((t2_3.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_4.b, t2_4.c, t1_4.a, t1_4.c
+ Hash Cond: ((t1_4.a = t2_4.b) AND (t1_4.b = t2_4.a) AND ((t1_4.c)::text = (t2_4.c)::text) AND ((t1_4.b + t1_4.a) = (t2_4.a + t2_4.b)))
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Hash
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: ((t2_4.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_5.b, t2_5.c, t1_5.a, t1_5.c
+ Hash Cond: ((t1_5.a = t2_5.b) AND (t1_5.b = t2_5.a) AND ((t1_5.c)::text = (t2_5.c)::text) AND ((t1_5.b + t1_5.a) = (t2_5.a + t2_5.b)))
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Hash
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: ((t2_5.b % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Sort Key: prt1_l_p1_p1.a, prt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt2_l_p1_p2.b, prt2_l_p1_p2.c
+ Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..79779d6
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,4118 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(47 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t2.a, t2.b
+ Sort Key: t1_3.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Sort Key: t1_4.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Sort Key: t1_5.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Sort Key: t1_3.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Sort Key: t1_4.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Sort Key: t1_5.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1_2.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(43 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(44 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+--
+-- negative testcases
+--
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out
index f06cfa4..16e7f56 100644
--- a/src/test/regress/expected/rangefuncs.out
+++ b/src/test/regress/expected/rangefuncs.out
@@ -1,18 +1,19 @@
SELECT name, setting FROM pg_settings WHERE name LIKE 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
CREATE TABLE foo2(fooid int, f2 int);
INSERT INTO foo2 VALUES(1, 11);
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 8641769..b61ca3b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -99,8 +99,9 @@ test: select_parallel
# ----------
# Another group of parallel tests
+# TODO: merge partition_join and multi_level_partition_join
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join multi_level_partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 835cf35..5b167b6 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -169,3 +169,5 @@ test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
+test: multi_level_partition_join
diff --git a/src/test/regress/sql/multi_level_partition_join.sql b/src/test/regress/sql/multi_level_partition_join.sql
new file mode 100644
index 0000000..31f0281
--- /dev/null
+++ b/src/test/regress/sql/multi_level_partition_join.sql
@@ -0,0 +1,95 @@
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..9b2baeb
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,520 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- negative testcases
+--
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
On Tue, Dec 27, 2016 at 11:01 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
PFA patch rebased after partitioning code was committed.
On Thu, Dec 1, 2016 at 4:32 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Hi Robert,
Sorry for delayed response.The attached patch implements following ideas:
1. At the time of creating paths - If the joining relations are both
partitioned and join can use partition-wise join, we create paths for
few child-joins. Similar to inheritance relations
(set_append_rel_pathlist()), we collect paths with similar properties
from all sampled child-joins and create one PartitionJoinPath with
each set of paths. The cost of the PartitionJoinPath is obtained by
multiplying the sum of costs of paths in the given set by the ratio of
(number of rows estimated in the parent-join/sum of rows in
child-joins).2. If the PartitionJoinPath emerges as the best path, we create paths
for each of the remaining child-joins. Then we collect paths with
properties same as the given PartitionJoinPath, one from each
child-join. These paths are converted into plans and a Merge/Append
plan is created combing these plans. The paths and plans for
child-join are created in a temporary memory context. The final plan
for each child-join is copied into planner's context and the temporary
memory context is reset.Right now, we choose 1% or 1 (whichever is higher) child-joins to base
PartitionJoinPath costs on.Memory consumption
-----------------------------
I tested a 5-way self-join for a table with 1000 partitions, each
partition having 1M rows. The memory consumed in standard_planner()
was measured with some granular tracking
(mem_usage_func_wise_measurement_slabwise.patch). Partition-wise join
consumed total of 289MB memory which is approx 6.6 times more than
non-partition-wise join which consumed 44MB. That's much better than
the earlier 16 times consumption for 5-way join with 100 partitions.The extra 245MB memory was consumed by child-join RelOptInfos (48MB),
SpecialJoinInfos for child-joins (64MB), restrictlist translation
(92MB), paths for sampled child-joins (1.5MB), building targetlists
for child-joins (7MB).In the earlier implementation, a given clause which was applicable to
multiple join orders was getting translated as many times as the join
orders it was applicable in. I changed RestrictInfo for parent to
store a list of RestrictInfos applicable to children to avoid multiple
translations.My earlier patch created the child-join plans in a temporary context
and then copied them into planner context since the translated clauses
were allocated memory in temporary memory context then. Now that they
are stored in planner's context, we can directly create the plan in
the planner's context.Third, I added code to free up child SpecialJoinInfos after using those.
As a result the total memory consumption now is 192MB, which is approx
4.4 times the memory consumed during planning in case of
non-partition-wise join.Choosing representative child-joins:
--------------------------------------------------
There's another angle to choosing representative child joins. In a
partitioned N-way join, different joins covering different subsets of
N relations, will have different size distributions across the
partitions. This means that the child-joins costed for (N-k) joins,
may be different for those required for (N-k+1) joins. With a factor
of 1% sampling, N is such that a child-join participates in 100 joins,
we will end up creating paths for all partitions before creating
PartitionJoinPaths for the final N-way join. Hopefully that will be a
rare case and usually we will end up using paths already created. We
can not avoid creating PartitionJoinPaths for subset joins, as there
might be cases when partition-wise join will be optimal for an N-k way
join but not for N-way join. We may avoid this if we choose
representative child-joins based on their positions, in which case, we
may end up with some or all of those being empty and thus skewing the
costs heavily.Partial paths
-----------------
AFAIU, we create partial paths for append relation, when all the
children have partial paths. Unlike parameterized paths or path with
pathkeys, there is no way to create a partial path for a normal path.
This means that unless we create paths for all child-joins, we can not
create partial paths for appendrel comprising of child-joins, and thus
can not use parallel query right now. This may not be that bad, since
it would be more efficient to run each child-join in a separate
worker, rather than using multiple workers for a single child-join.This still applies.
regression tests
----------------------
I observed that for small relations (1000 rows in each partition and
100 partitions), the size estimates in append relations and sum of
those in child relations are very different. As a result, the
extrapolated costs for PartitionJoinPaths as described above, are way
higher than costs of join of appends (or even append of joins if we
are to create paths for all child-joins). Thus with this approach, we
choose partition-wise join for large number of partitions with large
data (e.g. 1000 partitions with 1M rows each). These are certainly the
cases when partition-wise join is a big win. I have not tried to find
out a threshold above which partition-wise join gets chosen with above
approach, but it's going to be a larger threshold. That makes writing
regression tests difficult, as those will require large data. So, we
have to find a way so that we can test partition-wise join with
smaller data. There are few possibilities like 1. convert the fraction
of representative child-joins into GUC and setting it to 100% would
start choosing partition-wise joins for tables with a few hundred rows
per partition, like it did in earlier approach, 2. provide a way to
force partition-wise join whenever possible, by say costing
partition-wise joins much lesser than non-partition-wise join when a
GUC is set (e.g. enable_partition_wise_join with values always, never,
optimal or something like that).For now I have added a float GUC partition_wise_plan_weight. The
partition-wise join cost derived from the samples is multiplied by
this GUC and set as the cost of ParitionJoinPath. A value of 1 means
that the cost derived from the samples are used as is. A value higher
than 1 discourages use of partition-wise join and that lower than 1
encourages use of partition-wise join. I am not very keen on keeping
this GUC, in this form. But we need some way to run regression with
smaller data.For now I have disabled partition-wise join for multi-level
partitions. I will post a patch soon with that enabled.
PFA the patch (pg_dp_join_v6.patch) with some bugs fixed and rebased
on the latest code.
Also, PFA patch to support partition-wise join between multi-level
partitioned tables. I copied the Amit Langote's patch for translating
partition hierarchy into inheritance hierarchy and added code to
support partition-wise join. You had expressed some concerns about
Amit's approach in [1]/messages/by-id/CA+TgmoaEU10Kmdy44izcqJYLh1fkh58_6sbGGu0Q4b7PPE46eA@mail.gmail.com, but that discussion is still open. So, I
haven't merged those changes to partition-wise join patch. We may
continue to work on it as separate patch or I can include it in
partition-wise join main patch.
BTW, INSERT into multi-level partitioned tables is crashing with
latest head. The issue was reported in [2]/messages/by-id/CAKcux6=m1qyqB2k6cjniuMMrYXb75O-MB4qGQMu8zg-iGGLjDw@mail.gmail.com. Because of that
multi_level_partition_join test crashes in pg_dp_join_v6.patch.
Intestingly the crash vanishes when we apply patch supporting
mult-level partition-wise join.
[1]: /messages/by-id/CA+TgmoaEU10Kmdy44izcqJYLh1fkh58_6sbGGu0Q4b7PPE46eA@mail.gmail.com
[2]: /messages/by-id/CAKcux6=m1qyqB2k6cjniuMMrYXb75O-MB4qGQMu8zg-iGGLjDw@mail.gmail.com
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_v6.patchapplication/x-download; name=pg_dp_join_v6.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 66b059a..b1ea55a 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -911,7 +911,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
* We handle relations for foreign tables, joins between those and upper
* relations.
*/
- Assert(rel->reloptkind == RELOPT_JOINREL ||
+ Assert(IS_JOIN_REL(rel) ||
rel->reloptkind == RELOPT_BASEREL ||
rel->reloptkind == RELOPT_OTHER_MEMBER_REL ||
rel->reloptkind == RELOPT_UPPER_REL);
@@ -990,7 +990,7 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
@@ -1030,7 +1030,7 @@ deparseFromExpr(List *quals, deparse_expr_cxt *context)
/* For upper relations, scanrel must be either a joinrel or a baserel */
Assert(context->foreignrel->reloptkind != RELOPT_UPPER_REL ||
- scanrel->reloptkind == RELOPT_JOINREL ||
+ IS_JOIN_REL(scanrel) ||
scanrel->reloptkind == RELOPT_BASEREL);
/* Construct FROM clause */
@@ -1178,7 +1178,7 @@ deparseLockingClause(deparse_expr_cxt *context)
appendStringInfoString(buf, " FOR UPDATE");
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(rel))
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
else
@@ -1345,7 +1345,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
RelOptInfo *rel_o = fpinfo->outerrel;
RelOptInfo *rel_i = fpinfo->innerrel;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index fbe6929..74fca6b 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -721,8 +721,8 @@ get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel)
return useful_eclass_list;
/* If this is a child rel, we must use the topmost parent rel to search. */
- if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
- relids = find_childrel_top_parent(root, rel)->relids;
+ if (IS_OTHER_REL(rel))
+ relids = find_childrel_top_parent(root, rel);
else
relids = rel->relids;
@@ -1183,7 +1183,7 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
@@ -1249,7 +1249,7 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2529,7 +2529,7 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
@@ -2611,7 +2611,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind == RELOPT_JOINREL)
+ else if (IS_JOIN_REL(foreignrel))
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index fca8747..98fed55 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -20,6 +20,7 @@
#include "access/nbtree.h"
#include "access/sysattr.h"
#include "catalog/dependency.h"
+#include "catalog/heap.h"
#include "catalog/indexing.h"
#include "catalog/objectaddress.h"
#include "catalog/partition.h"
@@ -139,6 +140,8 @@ static int32 partition_bound_cmp(PartitionKey key,
static int partition_bound_bsearch(PartitionKey key,
PartitionBoundInfo boundinfo,
void *probe, bool probe_is_bound, bool *is_equal);
+static PartitionBoundInfo partition_bounds_copy(PartitionBoundInfo src,
+ PartitionKey key);
/* Support get_partition_for_tuple() */
static void FormPartitionKeyDatum(PartitionDispatch pd,
@@ -1990,3 +1993,250 @@ partition_bound_bsearch(PartitionKey key, PartitionBoundInfo boundinfo,
return lo;
}
+
+ /*
+ * Return a copy of given PartitionBoundInfo structure. The data types of bounds
+ * are described by given partition key specificiation.
+ */
+static PartitionBoundInfo
+partition_bounds_copy(PartitionBoundInfo src, PartitionKey key)
+{
+ PartitionBoundInfo dest;
+ int i;
+ int ndatums;
+ int partnatts;
+ int num_indexes;
+
+ dest = (PartitionBoundInfo) palloc(sizeof(PartitionBoundInfoData));
+
+ dest->strategy = src->strategy;
+ ndatums = dest->ndatums = src->ndatums;
+ partnatts = key->partnatts;
+
+ /* Range partitioned table has an extra index. */
+ num_indexes = key->strategy == PARTITION_STRATEGY_RANGE ? ndatums + 1 : ndatums;
+
+ /* List partitioned tables have only a single partition key. */
+ Assert(key->strategy != PARTITION_STRATEGY_LIST || partnatts == 1);
+
+ dest->datums = (Datum **) palloc(sizeof(Datum *) * ndatums);
+
+ for (i = 0; i < ndatums; i++)
+ {
+ int j;
+ dest->datums[i] = (Datum *) palloc(sizeof(Datum) * partnatts);
+
+ for (j = 0; j < partnatts; j++)
+ dest->datums[i][j] = datumCopy(src->datums[i][j],
+ key->parttypbyval[j],
+ key->parttyplen[j]);
+ }
+
+ if (src->content)
+ {
+ dest->content = (RangeDatumContent **) palloc(ndatums *
+ sizeof(RangeDatumContent *));
+ for (i = 0; i < ndatums; i++)
+ {
+ dest->content[i] = (RangeDatumContent *) palloc(partnatts *
+ sizeof(RangeDatumContent));
+
+ memcpy(dest->content[i], src->content[i],
+ sizeof(RangeDatumContent) * key->partnatts);
+ }
+ }
+ else
+ dest->content = NULL;
+
+ dest->indexes = (int *) palloc(sizeof(int) * num_indexes);
+ memcpy(dest->indexes, src->indexes, sizeof(int) * num_indexes);
+
+ dest->has_null = src->has_null;
+ dest->null_index = src->null_index;
+
+ return dest;
+}
+
+/*
+ * find_partition_scheme
+ *
+ * The function returns a canonical partition scheme which exactly matches the
+ * partitioning properties of the given relation if one exists in the of
+ * canonical partitioning schemes maintained in PlannerInfo. If none of the
+ * existing partitioning schemes match, the function creates a canonical
+ * partition scheme and adds it to the list.
+ *
+ * For an unpartitioned table or for a multi-level partitioned table it returns
+ * NULL.
+ */
+extern PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ int cnt_parts;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /*
+ * For a multi-level partitioned table, we do not retain the partitioning
+ * hierarchy while expanding RTE for the topmost parent. Thus the number of
+ * children as per root->append_rel_list does not match the number of
+ * partitions specified in the partition descriptor and hence the
+ * partitioning scheme of a multi-partitioned table does not reflect the
+ * true picture. So for now, treat a multi-partitioned table as not
+ * partitioned.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (has_subclass(part_desc->oids[cnt_parts]))
+ return NULL;
+ }
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * For types, it suffices to match the type id, mod and collation;
+ * len, byval and align are depedent on the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->parttypid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->parttypmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->parttypcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->boundinfo,
+ part_scheme->boundinfo))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->boundinfo = partition_bounds_copy(part_desc->boundinfo,
+ part_key);
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopfamily, part_key->partopfamily,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopcintype, part_key->partopcintype,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_types, part_key->parttypid,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ memcpy(part_scheme->key_typmods, part_key->parttypmod,
+ sizeof(int32) * partnatts);
+
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_collations, part_key->parttypcoll,
+ sizeof(Oid) * partnatts);
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_key_exprs
+ *
+ * Collect partition key expressions for a given base relation. The function
+ * converts any single column partition keys into corresponding Var nodes. It
+ * restamps Var nodes in partition key expressions by given varno. The
+ * partition key expressions are returned as an array of single element Lists
+ * to be stored in RelOptInfo of the base relation.
+ */
+extern List **
+build_baserel_partition_key_exprs(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (lc == NULL)
+ elog(ERROR, "wrong number of partition key expressions");
+
+ /* Re-stamp the expressions with given varno. */
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 242d6d2..75c95e4 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -721,7 +721,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
{
ListCell *lc;
- Assert(joinrel->reloptkind == RELOPT_JOINREL);
+ Assert(IS_JOIN_REL(joinrel));
foreach(lc, joinrel->pathlist)
{
@@ -786,7 +786,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->outerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->outerjoinpath = foreign_path->fdw_outerpath;
}
@@ -795,7 +795,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->innerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->innerjoinpath = foreign_path->fdw_outerpath;
}
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 6955298..6d26688 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2049,6 +2049,14 @@ _copyRestrictInfo(const RestrictInfo *from)
COPY_SCALAR_FIELD(hashjoinoperator);
COPY_SCALAR_FIELD(left_bucketsize);
COPY_SCALAR_FIELD(right_bucketsize);
+ /*
+ * Do not copy parent_rinfo and child_rinfos because 1. they create a
+ * circular dependency between child and parent RestrictInfo 2. dropping
+ * those links just means that we loose some memory optimizations. 3. There
+ * is a possibility that the child and parent RestrictInfots themselves may
+ * have got copied and thus the old links may no longer be valid. The
+ * caller may set up those links itself, if needed.
+ */
return newnode;
}
diff --git a/src/backend/optimizer/README b/src/backend/optimizer/README
index 775bcc3..d755f1f 100644
--- a/src/backend/optimizer/README
+++ b/src/backend/optimizer/README
@@ -974,3 +974,56 @@ be desirable to postpone the Gather stage until as near to the top of the
plan as possible. Expanding the range of cases in which more work can be
pushed below the Gather (and costing them accurately) is likely to keep us
busy for a long time to come.
+
+Partition-wise joins
+--------------------
+A join between two similarly partitioned tables can be broken down into joins
+between their matching partitions if there exists an equi-join condition
+between the partition keys of the joining tables. The equi-join between
+partition keys implies that for a given row in a given partition of a given
+partitioned table, its joining row, if exists, should exist only in the
+matching partition of the other partitioned table; no row from non-matching
+partitions in the other partitioned table can join with the given row from the
+first table. This condition allows the join between partitioned table to be
+broken into joins between the matching partitions. The resultant join is
+partitioned in the same way as the joining relations, thus allowing an N-way
+join between similarly partitioned tables having equi-join condition between
+their partition keys to be broken down into N-way joins between their matching
+partitions. This technique of breaking down a join between partition tables
+into join between their partitions is called partition-wise join. We will use
+term "partitioned relation" for both partitioned table as well as join between
+partitioned tables which can use partition-wise join technique.
+
+Partitioning properties of a partitioned table are stored in
+PartitionSchemeData structure. Planner maintains a list of canonical partition
+schemes (distinct PartitionSchemeData objects) so that any two partitioned
+relations with same partitioning scheme share the same PartitionSchemeData
+object. This reduces memory consumed by PartitionSchemeData objects and makes
+it easy to compare the partition schemes of joining relations. RelOptInfos of
+partitioned relations hold partition key expressions and the RelOptInfos of
+the partition relations of that relation.
+
+Partition-wise joins are planned in two phases
+
+1. First phase creates the RelOptInfos for joins between matching partitions,
+henceforth referred to as child-joins. The number of paths created for a
+child-join i.e. join between partitions is same as the number of paths created
+for join between parents. That number grows exponentially with the number of
+base relations being joined. The time and memory consumed to create paths for
+each child-join will be proporional to the number of partitions. This will not
+scale well with thousands of partitions. Instead of that we estimate
+partition-wise join cost based on the costs of sampled child-joins. We choose
+child-joins with higher sizes to have realistic estimates. If the number of
+sampled child-joins is same as the number of live child-joins, we create append
+paths as we know costs of all required child-joins. Otherwise we create
+PartitionJoinPaths with cost estimates based on the costs of sampled
+child-joins. While creating append paths or PartitionJoin paths we create paths
+for all the different possible parameterizations and pathkeys available in the
+sampled child-joins.
+
+2. If PartitionJoinPath emerges as the best possible path, we create paths for
+each unsampled child-join. From every child-join we choose the cheapest path
+with same parameterization or pathkeys as the PartitionJoinPath. This path is
+converted into a plan and all the child-join plans are combined using an Append
+or MergeAppend plan as appropriate. We use a fresh memory context for planning
+each unsampled child-join, thus reducing memory consumption.
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 9753a26..0a2c131 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -18,8 +18,10 @@
#include <limits.h>
#include <math.h>
+#include "miscadmin.h"
#include "access/sysattr.h"
#include "access/tsmapi.h"
+#include "catalog/partition.h"
#include "catalog/pg_class.h"
#include "catalog/pg_operator.h"
#include "catalog/pg_proc.h"
@@ -44,6 +46,7 @@
#include "parser/parsetree.h"
#include "rewrite/rewriteManip.h"
#include "utils/lsyscache.h"
+#include "utils/rel.h"
/* results of subquery_is_pushdown_safe */
@@ -93,8 +96,8 @@ static void set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
static void set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
static void generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels,
- List *all_child_pathkeys);
+ List *live_childrels, List *all_child_pathkeys,
+ bool partition_join_path);
static Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
RelOptInfo *rel,
Relids required_outer);
@@ -126,6 +129,8 @@ static void subquery_push_qual(Query *subquery,
static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels, bool partition_join_path);
/*
@@ -868,6 +873,34 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ Oid *part_oids = NULL;
+ int nparts = 0;
+
+ /*
+ * We require OIDs of the partitions to arrange the child RelOptInfos to
+ * match the lists/ranges specified in the partitioning scheme. Fetch those
+ * here so as keep those handy when going to child RelOptInfos below.
+ */
+ if (rel->part_scheme)
+ {
+ RangeTblEntry *rte = root->simple_rte_array[rel->relid];
+
+ /*
+ * We need not lock the relation since it was already locked, either by
+ * the rewriter or when expand_inherited_rtentry() added it to the
+ * query's rangetable.
+ */
+ Relation relation = heap_open(rte->relid, NoLock);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+
+ part_oids = part_desc->oids;
+ nparts = part_desc->nparts;
+
+ Assert(part_oids && nparts > 0);
+
+ rel->part_rels = (RelOptInfo **)palloc0(sizeof(RelOptInfo *) * nparts);
+ heap_close(relation, NoLock);
+ }
/*
* Initialize to compute size estimates for whole append relation.
@@ -899,6 +932,8 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Node *childqual;
ListCell *parentvars;
ListCell *childvars;
+ int cnt_parts;
+ List *appinfos = list_make1(appinfo);
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -912,8 +947,95 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* add_base_rels_to_query.
*/
childrel = find_base_rel(root, childRTindex);
+
+ /*
+ * Recursively save topmost parent's relid in RelOptInfos of
+ * partitions.
+ */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
+ /*
+ * For two partitioned tables with the same partitioning scheme, it is
+ * assumed that the Oids of matching partitions from both the tables
+ * are placed at the same position in the array of partition oids in
+ * respective partition descriptors. Saving the RelOptInfo of a
+ * partition in the same cardinal position as its Oid makes it easy to
+ * find the RelOptInfos of matching partitions for partition-wise join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+
+ /*
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for building pair-wise
+ * join relations. Partition tables should have same layout as the
+ * parent table and hence should not need any translation. But rest of
+ * the code still uses inheritance mechanism. So does this code. For
+ * other inherited children, attr_needed is only examined for base
+ * relations, no otherrels. So we compute attr_needed only for children
+ * of a partitioned table.
+ */
+ if (rel->part_scheme)
+ {
+ AttrNumber attno;
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /* Parent Var translates to child Var. */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
+ }
+
+ /*
+ * Copy/Modify targetlist. Even if this child is deemed empty, we need
+ * its targetlist in case it falls on nullable side in a child-join
+ * because of partition-wise join.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs, appinfos);
+
/*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
@@ -931,7 +1053,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childquals = get_all_actual_clauses(rel->baserestrictinfo);
childquals = (List *) adjust_appendrel_attrs(root,
(Node *) childquals,
- appinfo);
+ appinfos);
childqual = eval_const_expressions(root, (Node *)
make_ands_explicit(childquals));
if (childqual && IsA(childqual, Const) &&
@@ -960,24 +1082,9 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
- childrel->joininfo = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->joininfo,
- appinfo);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo);
+ /* CE failed, so finish copying/modifying join quals. */
+ childrel->joininfo = build_child_clauses(root, rel->joininfo,
+ appinfos);
/*
* We have to make child entries in the EquivalenceClass data
@@ -992,14 +1099,6 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
- * Note: we could compute appropriate attr_needed data for the child's
- * variables, by transforming the parent's attr_needed through the
- * translated_vars mapping. However, currently there's no need
- * because attr_needed is only examined for base relations not
- * otherrels. So we just leave the child's attr_needed empty.
- */
-
- /*
* If parallelism is allowable for this query in general, see whether
* it's allowable for this childrel in particular. But if we've
* already decided the appendrel is not parallel-safe as a whole,
@@ -1080,6 +1179,16 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ if (!rel->part_rels[cnt_parts])
+ elog(ERROR, "could not find the RelOptInfo of a partition with oid %u",
+ part_oids[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
@@ -1122,19 +1231,11 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
- * Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * Generate access paths for each member relation and remember the
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
@@ -1142,7 +1243,6 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -1177,6 +1277,64 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ /* Add Append/MergeAppend paths to the "append" relation. */
+ add_paths_to_append_rel(root, rel, live_childrels, false);
+}
+
+/*
+ * add_paths_to_append_rel
+ * Generate Append/MergeAppend paths for given "append" relation. An
+ * "append" relation can be a base parent relation or a join between
+ * partitioned tables.
+ *
+ * The function collects all parameterizations and orderings supported by the
+ * non-dummy children. For every such parameterization or ordering, it creates
+ * an append path collecting one path from each non-dummy child with given
+ * parameterization or ordering. Similarly it collects partial paths from
+ * non-dummy children to create partial append paths.
+ */
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels, bool partition_join_path)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * While creating PartitionJoinPath, we sample paths from only a few child
+ * relations. Even if all of sampled children have partial paths, it's not
+ * guaranteed that all the unsampled children will have partial paths.
+ * Hence we do not create partial PartitionJoinPaths.
+ */
+ partial_subpaths_valid = !partition_join_path ? true : false;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (live_childrels == NIL)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
@@ -1267,7 +1425,17 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(rel, subpaths,
+ NULL);
+ else
+ path = (Path *) create_append_path(rel, subpaths, NULL, 0);
+
+ add_path(rel, path);
+ }
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1278,6 +1446,8 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
ListCell *lc;
int parallel_workers = 0;
+ Assert(!partition_join_path);
+
/*
* Decide on the number of workers to request for this append path.
* For now, we just use the maximum value from among the members. It
@@ -1304,7 +1474,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
*/
if (subpaths_valid)
generate_mergeappend_paths(root, rel, live_childrels,
- all_child_pathkeys);
+ all_child_pathkeys, partition_join_path);
/*
* Build Append paths for each parameterization seen among the child rels.
@@ -1345,8 +1515,16 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(rel, subpaths, required_outer);
+ else
+ path = (Path *) create_append_path(rel, subpaths, required_outer, 0);
+
+ add_path(rel, path);
+ }
}
}
@@ -1376,7 +1554,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
static void
generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *live_childrels,
- List *all_child_pathkeys)
+ List *all_child_pathkeys, bool partition_join_path)
{
ListCell *lcp;
@@ -1387,6 +1565,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *total_subpaths = NIL;
bool startup_neq_total = false;
ListCell *lcr;
+ Path *path;
/* Select the child paths for this ordering... */
foreach(lcr, live_childrels)
@@ -1434,17 +1613,29 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
}
/* ... and build the MergeAppend paths */
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- startup_subpaths,
- pathkeys,
- NULL));
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path_with_pathkeys(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+
if (startup_neq_total)
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- total_subpaths,
- pathkeys,
- NULL));
+ {
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path_with_pathkeys(root,
+ rel,
+ total_subpaths,
+ pathkeys, NULL);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ total_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+ }
}
}
@@ -2186,15 +2377,27 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
/*
* Run generate_gather_paths() for each just-processed joinrel. We
- * could not do this earlier because both regular and partial paths
- * can get added to a particular joinrel at multiple times within
- * join_search_one_level. After that, we're done creating paths for
- * the joinrel, so run set_cheapest().
+ * could not do this earlier because both regular and partial paths can
+ * get added to a particular joinrel at multiple times within
+ * join_search_one_level.
+ *
+ * Similarly, create paths for joinrels which used partition-wise join
+ * technique. generate_partition_wise_join_paths() creates paths for
+ * only few of the child-joins with highest sizes. Though we calculate
+ * size of a child-join only once; when it gets created, it may be
+ * deemed empty while considering various join orders within
+ * join_search_one_level.
+ *
+ * After that, we're done creating paths for the joinrel, so run
+ * set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
rel = (RelOptInfo *) lfirst(lc);
+ /* Create paths for partition-wise joins. */
+ generate_partition_wise_join_paths(root, rel);
+
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
@@ -2866,6 +3069,151 @@ remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel)
}
}
+/* Fraction of child relations to base cost on. */
+#define FRACTION_PARTS_TO_PLAN 0.01
+
+/*
+ * generate_partition_wise_join_paths
+ *
+ * Create paths representing partition-wise join for given partitioned
+ * join relation.
+ *
+ * The number of paths created for a child-join is same as the number of paths
+ * created for join between parents. That number grows exponentially with the
+ * number of base relations being joined. The time and memory consumed to
+ * create paths for each child-join will be proporional to the number of
+ * partitions. This will not scale well with thousands of partitions. Instead
+ * of that we estimate partition-wise join cost based on the costs of sampled
+ * child-joins. We choose child-joins with higher sizes to have realistic
+ * estimates.
+ *
+ * This must be called after we have considered all joining orders since
+ * certain join orders may allow us to deem a child-join as dummy.
+ */
+void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *sampled_children = NIL;
+ List *ordered_child_nos = NIL;
+ int cnt_part;
+ int num_part_to_plan;
+ int num_parts;
+ bool partition_join_path = false;
+ int num_dummy_parts = 0;
+ ListCell *lc;
+
+ /* Handle only join relations. */
+ if (!IS_JOIN_REL(rel))
+ return;
+
+ /*
+ * If none of the join orders for this relation could use partition-wise
+ * join technique, the join is not partitioned. Reset the partitioning
+ * scheme.
+ */
+ if (!rel->part_rels)
+ rel->part_scheme = NULL;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || IS_DUMMY_REL(rel))
+ return;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ num_parts = rel->part_scheme->nparts;
+
+ /* Calculate number of child-joins to sample. */
+ num_part_to_plan = num_parts * FRACTION_PARTS_TO_PLAN;
+ if (num_part_to_plan < 1)
+ num_part_to_plan = 1;
+
+ /* Order the child-join relations by their size. */
+ for (cnt_part = 0; cnt_part < num_parts; cnt_part++)
+ {
+ RelOptInfo *child_rel = rel->part_rels[cnt_part];
+ ListCell *insert_after;
+
+ insert_after = NULL;
+
+ /* Dummy children will not be scanned, so ingore those. */
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+ /*
+ * Add this relation to the list of samples ordered by the increasing
+ * number of rows at appropriate place.
+ */
+ foreach (lc, ordered_child_nos)
+ {
+ int child_no = lfirst_int(lc);
+ RelOptInfo *other_childrel = rel->part_rels[child_no];
+
+ /*
+ * Keep track of child with lowest number of rows but higher than the
+ * that of the child being inserted. Insert the child before a
+ * child with highest number of rows lesser than it.
+ */
+ if (child_rel->rows <= other_childrel->rows)
+ insert_after = lc;
+ else
+ break;
+ }
+
+ if (insert_after)
+ lappend_cell_int(ordered_child_nos, insert_after, cnt_part);
+ else
+ ordered_child_nos = lcons_int(cnt_part, ordered_child_nos);
+ }
+
+ /*
+ * Create paths for the child-joins as they appear in the list ordered by
+ * their size. Stop when we have created paths for required number of
+ * child-joins.
+ */
+ foreach (lc, ordered_child_nos)
+ {
+ int child_no = lfirst_int(lc);
+ RelOptInfo *child_rel = rel->part_rels[child_no];
+
+ /* Create paths for this child. */
+ add_paths_to_child_joinrel(root, rel, child_no);
+
+ /* Dummy children will not be scanned, so ingore those. */
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ sampled_children = lappend(sampled_children, child_rel);
+
+ if (list_length(sampled_children) >= num_part_to_plan)
+ break;
+ }
+
+ /*
+ * If the number of samples is same as the number of live children, an
+ * append path will do. Otherwise, we will cost the partition-wise join
+ * based on the sampled children using PartitionJoinPath.
+ */
+ if (num_part_to_plan < num_parts - num_dummy_parts)
+ partition_join_path = true;
+
+ /* Add paths for partition-wise join based on the sampled children. */
+ add_paths_to_append_rel(root, rel, sampled_children, partition_join_path);
+
+ if (sampled_children)
+ list_free(sampled_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
*****************************************************************************/
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index 415edad..ba2b238 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,8 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
+double partition_wise_plan_weight = DEFAULT_PARTITION_WISE_PLAN_WEIGHT;
typedef struct
{
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index 0e50ad5..b1ea2ba 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -972,6 +972,10 @@ generate_base_implied_equalities_broken(PlannerInfo *root,
* appropriate clauses using child EC members. add_child_rel_equivalences
* must already have been done for the child rel.
*
+ * For a join between child relations, joinrelids, outer_relids and
+ * inner_rel all point to child relations. In this case, we need to find the
+ * parent relids to search the applicable equivalence classes.
+ *
* The results are sufficient for use in merge, hash, and plain nestloop join
* methods. We do not worry here about selecting clauses that are optimal
* for use in a parameterized indexscan. indxpath.c makes its own selections
@@ -1021,12 +1025,27 @@ generate_join_implied_equalities_for_ecs(PlannerInfo *root,
ListCell *lc;
/* If inner rel is a child, extra setup work is needed */
- if (inner_rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ if (IS_OTHER_REL(inner_rel))
{
+ RelOptInfo *outer_rel;
+ Relids nominal_outer_relids;
+
+ if (bms_num_members(outer_relids) > 1)
+ outer_rel = find_join_rel(root, outer_relids);
+ else
+ outer_rel = find_base_rel(root, bms_singleton_member(outer_relids));
+
/* Fetch relid set for the topmost parent rel */
- nominal_inner_relids = find_childrel_top_parent(root, inner_rel)->relids;
- /* ECs will be marked with the parent's relid, not the child's */
- nominal_join_relids = bms_union(outer_relids, nominal_inner_relids);
+ nominal_inner_relids = find_childrel_top_parent(root, inner_rel);
+
+ /* ECs will be marked with the parent's relid, not the child's. */
+ if (outer_rel && IS_OTHER_REL(outer_rel))
+ {
+ nominal_outer_relids = find_childrel_top_parent(root, outer_rel);
+ nominal_join_relids = bms_union(nominal_outer_relids, nominal_inner_relids);
+ }
+ else
+ nominal_join_relids = bms_union(outer_relids, nominal_inner_relids);
}
else
{
@@ -2062,7 +2081,7 @@ add_child_rel_equivalences(PlannerInfo *root,
child_expr = (Expr *)
adjust_appendrel_attrs(root,
(Node *) cur_em->em_expr,
- appinfo);
+ list_make1(appinfo));
/*
* Transform em_relids to match. Note we do *not* do
@@ -2364,8 +2383,8 @@ eclass_useful_for_merging(PlannerInfo *root,
*/
/* If specified rel is a child, we must consider the topmost parent rel */
- if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
- relids = find_childrel_top_parent(root, rel)->relids;
+ if (IS_OTHER_REL(rel))
+ relids = find_childrel_top_parent(root, rel);
else
relids = rel->relids;
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index b5cbcf4..d794038 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -25,9 +25,19 @@
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+/*
+ * Paths parameterized by the parent can be considered to be parameterized by
+ * any of its child.
+ */
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
@@ -141,6 +151,19 @@ add_paths_to_joinrel(PlannerInfo *root,
foreach(lc, root->join_info_list)
{
SpecialJoinInfo *sjinfo2 = (SpecialJoinInfo *) lfirst(lc);
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between child relations, even if there is a SpecialJoinInfo node for
+ * the join between the topmost parents. Hence while calculating Relids
+ * set representing the restriction, consider relids of topmost parent
+ * of partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
/*
* SJ is relevant to this join if we have some part of its RHS
@@ -149,16 +172,16 @@ add_paths_to_joinrel(PlannerInfo *root,
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo2->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo2->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo2->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo2->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_righthand))
+ bms_overlap(joinrelids, sjinfo2->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_lefthand));
@@ -288,6 +311,22 @@ try_nestloop_path(PlannerInfo *root,
JoinCostWorkspace workspace;
/*
+ * For a join between child relations, if the inner path is parameterized
+ * by the parent of the outer relation, create a nestloop join path with
+ * inner relation parameterized by the outer relation by translating the
+ * inner path to be parameterized by the outer child relation.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_by_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 01d4fea..7839f0f 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -14,9 +14,14 @@
*/
#include "postgres.h"
+#include "miscadmin.h"
+#include "catalog/partition.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
@@ -32,7 +37,19 @@ static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
-
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
/*
* join_search_one_level
@@ -724,6 +741,31 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Add paths to the given joinrel for given pair of joining relations. The
+ * SpecialJoinInfo provides details about the join and the restrictlist
+ * contains the join clauses and the other clauses applicable for given pair
+ * of the joining relations.
+ */
+
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
@@ -868,13 +910,8 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
-
/*
* have_join_order_restriction
* Detect whether the two relations should be joined to satisfy
@@ -1249,3 +1286,476 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
}
return false;
}
+
+/* Free SpecialJoinInfo. */
+static void
+free_special_join_info(SpecialJoinInfo *sjinfo)
+{
+ bms_free(sjinfo->min_lefthand);
+ bms_free(sjinfo->syn_lefthand);
+ bms_free(sjinfo->syn_righthand);
+ pfree(sjinfo);
+}
+
+/*
+ * Assess whether join between given two partitioned relations can be broken
+ * down into joins between matching partitions; a technique called
+ * "partition-wise join"
+ *
+ * Partition-wise join is possible when a. Joining relations have same
+ * partitioning scheme b. There exists an equi-join between the partition keys
+ * of the two relations.
+ *
+ * Partition-wise join is planned as follows (details: optimizer/README.)
+ *
+ * 1. Create the RelOptInfos for joins between matching partitions i.e
+ * child-joins and estimate sizes of those. This function is responsible for
+ * this phase.
+ *
+ * 2. Add paths representing partition-wise join. The second phase is
+ * implemented by generate_partition_wise_join_paths(). In order to save time
+ * and memory consumed in creating paths for every child-join, we create paths
+ * for only few child-joins.
+ *
+ * 3. Create merge/append plan to combining plans for every child-join,
+ * creating paths for remaining child-joins.
+ *
+ * The RelOptInfo, SpecialJoinInfo and restrictlist for each child join are
+ * obtained by translating the respective parent join structures.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ PartitionScheme part_scheme;
+ PartitionedJoin *partitioned_join;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If any of the joining parent relations is proven empty, either the join
+ * will be empty (INNER join) or will have the inner side all nullified. We
+ * take care of such cases when creating join paths for parent relations.
+ * Nothing to be done here. Also, nothing to do, if the parent join is
+ * proven empty.
+ */
+ if (IS_DUMMY_REL(rel1) || IS_DUMMY_REL(rel2) || IS_DUMMY_REL(joinrel))
+ return;
+
+ /*
+ * Partitioning scheme in join relation indicates a possibilty that the
+ * join may be partitioned, but it's not necessary that every pair of
+ * joining relations can use partition-wise join technique. If one of
+ * joining relations turns out to be unpartitioned, this pair of joining
+ * relations can not use partition-wise join technique.
+ */
+ if (!rel1->part_scheme || !rel2->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, this pair of joining relations can not use
+ * partition-wise technique.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ /*
+ * The partition scheme of the join relation should match that of the
+ * joining relations.
+ */
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ /* We should have RelOptInfos of the partitions available. */
+ Assert(rel1->part_rels && rel2->part_rels);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = part_scheme->nparts;
+
+ /*
+ * We do not store information about valid pairs of joining child
+ * relations. The pair of joining relations for a child-join can be derived
+ * from valid pairs of joining parent relations. Amongst the valid pairs of
+ * parent joining relations, only those which result in partitioned join
+ * matter for partition-wise join. Remember those so that we can use them
+ * for creating paths for few child-joins in
+ * generate_partition_wise_join_paths() later.
+ */
+ partitioned_join = (PartitionedJoin *) palloc(sizeof(PartitionedJoin));
+ partitioned_join->rel1 = rel1;
+ partitioned_join->rel2 = rel2;
+ partitioned_join->sjinfo = copyObject(parent_sjinfo);
+ partitioned_join->restrictlist = parent_restrictlist;
+ joinrel->partitioned_joins = lappend(joinrel->partitioned_joins,
+ partitioned_join);
+
+ elog(DEBUG3, "join between relations %s and %s is considered for partition-wise join.",
+ bmsToString(rel1->relids), bmsToString(rel2->relids));
+
+ /* We are done if child RelOptInfos are already created. */
+ if (joinrel->part_rels)
+ return;
+
+ /* Create all the child RelOptInfos. */
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create child join relations for this partitioned join. While doing so,
+ * we estimate sizes of these child join relations. These estimates are
+ * used to find the representative child relations used for costing the
+ * partition-wise join later.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ RelOptInfo *child_joinrel;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ Assert (!joinrel->part_rels[cnt_parts]);
+
+ child_joinrel = build_child_join_rel(root, child_rel1, child_rel2,
+ joinrel, parent_sjinfo->jointype);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, parent_restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, parent_sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+ /*
+ * Set estimates of the child-joinrel's size.
+ */
+ set_joinrel_size_estimates(root, child_joinrel, child_rel1, child_rel2,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the child relations themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+}
+
+/*
+ * add_paths_to_child_join
+ * Add paths to 'child_id'th child of given parent join relation.
+ *
+ * The function creates paths for given child-join by joining corresponding
+ * children of every pair of joining parent relations which produces
+ * partitioned join. Since we create paths only for sampled child-joins, either
+ * of the children being joined may not have paths. In that case, this function
+ * is called recursively to populate paths for those.
+ */
+void
+add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
+ int child_id)
+{
+ ListCell *lc;
+ RelOptInfo *child_joinrel = parent_joinrel->part_rels[child_id];
+
+ Assert(IS_JOIN_REL(parent_joinrel));
+
+ /* If this child relation already has paths, nothing to do. */
+ if (child_joinrel->cheapest_total_path)
+ return;
+
+ /* A dummy relation will have a dummy path as the cheapest path. */
+ Assert(!is_dummy_rel(child_joinrel));
+
+ /*
+ * For every partitioned join order, calculate paths for the joining
+ * child relations and then calculate paths for given child.
+ */
+ foreach (lc, parent_joinrel->partitioned_joins)
+ {
+ PartitionedJoin *pj = lfirst(lc);
+ RelOptInfo *rel1 = pj->rel1;
+ RelOptInfo *rel2 = pj->rel2;
+ RelOptInfo *child_rel1 = rel1->part_rels[child_id];
+ RelOptInfo *child_rel2 = rel2->part_rels[child_id];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+
+ /*
+ * Add paths to joining relation if it is a join itself.
+ * Paths for child base relations are created in
+ * set_append_rel_pathlist().
+ */
+ if (IS_JOIN_REL(pj->rel1))
+ add_paths_to_child_joinrel(root, rel1, child_id);
+
+ if (IS_JOIN_REL(pj->rel2))
+ add_paths_to_child_joinrel(root, rel2, child_id);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, pj->sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, pj->restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /* Add paths for child join. */
+ populate_joinrel_with_paths(root, rel1->part_rels[child_id],
+ rel2->part_rels[child_id], child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /* Add partition-wise join paths for partitioned child-joins. */
+ generate_partition_wise_join_paths(root, child_joinrel);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+
+ set_cheapest(child_joinrel);
+}
+
+/*
+ * Construct the SpecialJoinInfo for a child-join by translating
+ * SpecialJoinInfo for the join between parents. left_relids and right_relids
+ * are the relids of left and right side of the join respectively.
+ */
+static SpecialJoinInfo *
+build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids)
+{
+ SpecialJoinInfo *sjinfo = makeNode(SpecialJoinInfo);
+ MemoryContext old_context;
+ List *left_appinfos = find_appinfos_by_relids(root, left_relids);
+ List *right_appinfos = find_appinfos_by_relids(root, right_relids);
+
+ memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
+
+ sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
+ left_appinfos);
+ sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
+ right_appinfos);
+ sjinfo->syn_lefthand = adjust_child_relids(sjinfo->syn_lefthand,
+ left_appinfos);
+ sjinfo->syn_righthand = adjust_child_relids(sjinfo->syn_righthand,
+ right_appinfos);
+
+ /*
+ * Replace the Var nodes of parent with those of children in expressions.
+ * This function may be called within a temporary context, but the
+ * expressions will be shallow-copied into the plan. Hence copy those in
+ * the planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ sjinfo->semi_rhs_exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ right_appinfos);
+ MemoryContextSwitchTo(old_context);
+
+ list_free(left_appinfos);
+ list_free(right_appinfos);
+
+ return sjinfo;
+}
+
+/*
+ * Replace parent relids by child relids in the copy of given relid set.
+ */
+Relids
+adjust_child_relids(Relids relids, List *append_rel_infos)
+{
+ ListCell *lc;
+
+ /* Ensure we have a modifiable copy. */
+ relids = bms_copy(relids);
+ foreach (lc, append_rel_infos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ /* Remove parent, add child */
+ if (bms_is_member(appinfo->parent_relid, relids))
+ {
+ relids = bms_del_member(relids, appinfo->parent_relid);
+ relids = bms_add_member(relids, appinfo->child_relid);
+ }
+ }
+
+ return relids;
+}
+
+/*
+ * Returns true if there exists an equi-join condition for each pair of
+ * partition key from given relations being joined.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ /*
+ * This function should be called when the joining relations have same
+ * partitioning scheme.
+ */
+ Assert(rel1->part_scheme == rel2->part_scheme);
+ Assert(part_scheme);
+
+ num_pks = part_scheme->partnatts;
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip clauses which can not be used for a join. */
+ if (!rinfo->can_join)
+ continue;
+
+ /* Skip clauses which are not equality conditions. */
+ if (rinfo->hashjoinoperator == InvalidOid && !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+
+ /* Match the operands to the relation. */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ /*
+ * If the clause refers to different partition keys from
+ * both relations, it can not be used for partition-wise join.
+ */
+ if (ipk1 != ipk2)
+ continue;
+
+ /*
+ * The clause allows partition-wise join if only it uses the same
+ * operator family as that specified by the partition key.
+ */
+ if (!list_member_oid(rinfo->mergeopfamilies,
+ part_scheme->partopfamily[ipk1]))
+ continue;
+
+ /* Mark the partition key as having an equi-join clause. */
+ pk_has_clause[ipk1] = true;
+ }
+
+ /* Check whether every partition key has an equi-join condition. */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * Find the partition key from the given relation matching the given
+ * expression. If found, return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks;
+
+ /* This function should be called only for partitioned relations. */
+ Assert(rel->part_scheme);
+
+ num_pks = rel->part_scheme->partnatts;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() simplifies multiple
+ * RelabelType nodes into one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/path/pathkeys.c b/src/backend/optimizer/path/pathkeys.c
index 4436ac1..def64e3 100644
--- a/src/backend/optimizer/path/pathkeys.c
+++ b/src/backend/optimizer/path/pathkeys.c
@@ -1088,12 +1088,25 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
int necs;
ListCell *lc;
int j;
+ Relids relids;
/* Might have no mergeclauses */
if (nClauses == 0)
return NIL;
/*
+ * For a child join relation, use parent relids to find potential join
+ * partners (see code below) from equivalence classes. A potential join
+ * partner of parent also indicates potential join partner of the child. By
+ * using only parent relids, we avoid scoring an equivalence class multiple
+ * times once for parent and then for all of its children.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
+ /*
* Make arrays of the ECs used by the mergeclauses (dropping any
* duplicates) and their "popularity" scores.
*/
@@ -1133,7 +1146,7 @@ select_outer_pathkeys_for_merge(PlannerInfo *root,
/* Potential future join partner? */
if (!em->em_is_const && !em->em_is_child &&
- !bms_overlap(em->em_relids, joinrel->relids))
+ !bms_overlap(em->em_relids, relids))
score++;
}
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index ad49674..3a223c8 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -30,6 +30,7 @@
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/paths.h"
+#include "optimizer/pathnode.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
#include "optimizer/planmain.h"
@@ -42,6 +43,7 @@
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
/*
@@ -145,6 +147,9 @@ static CustomScan *create_customscan_plan(PlannerInfo *root,
static NestLoop *create_nestloop_plan(PlannerInfo *root, NestPath *best_path);
static MergeJoin *create_mergejoin_plan(PlannerInfo *root, MergePath *best_path);
static HashJoin *create_hashjoin_plan(PlannerInfo *root, HashPath *best_path);
+static Plan *create_partition_plan(PlannerInfo *root, Path *best_path);
+static Plan *create_partition_join_plan(PlannerInfo *root,
+ PartitionJoinPath *best_path);
static Node *replace_nestloop_params(PlannerInfo *root, Node *expr);
static Node *replace_nestloop_params_mutator(Node *node, PlannerInfo *root);
static void process_subquery_nestloop_params(PlannerInfo *root,
@@ -241,7 +246,8 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
@@ -367,12 +373,8 @@ create_plan_recurse(PlannerInfo *root, Path *best_path, int flags)
(JoinPath *) best_path);
break;
case T_Append:
- plan = create_append_plan(root,
- (AppendPath *) best_path);
- break;
case T_MergeAppend:
- plan = create_merge_append_plan(root,
- (MergeAppendPath *) best_path);
+ plan = create_partition_plan(root, best_path);
break;
case T_Result:
if (IsA(best_path, ProjectionPath))
@@ -1115,6 +1117,30 @@ create_merge_append_plan(PlannerInfo *root, MergeAppendPath *best_path)
}
/*
+ * create_partition_plan
+ * Creates an Merge/Append plan as specified by the "best path".
+ *
+ * Returns a Plan node.
+ */
+static Plan *
+create_partition_plan(PlannerInfo *root, Path *best_path)
+{
+ Plan *plan;
+
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root, (PartitionJoinPath *)best_path);
+ else if (best_path->pathtype == T_Append)
+ plan = create_append_plan(root, (AppendPath *) best_path);
+ else
+ {
+ Assert(best_path->pathtype == T_MergeAppend);
+ plan = create_merge_append_plan(root, (MergeAppendPath *) best_path);
+ }
+
+ return plan;
+}
+
+/*
* create_result_plan
* Create a Result plan for 'best_path'.
* This is only used for degenerate cases, such as a query with an empty
@@ -1513,7 +1539,7 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
@@ -3530,6 +3556,8 @@ create_mergejoin_plan(PlannerInfo *root,
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
@@ -3537,10 +3565,10 @@ create_mergejoin_plan(PlannerInfo *root,
* best to request a small tlist so we aren't sorting more data than
* necessary.
*/
- outer_plan = create_plan_recurse(root, best_path->jpath.outerjoinpath,
+ outer_plan = create_plan_recurse(root, outer_path,
(best_path->outersortkeys != NIL) ? CP_SMALL_TLIST : 0);
- inner_plan = create_plan_recurse(root, best_path->jpath.innerjoinpath,
+ inner_plan = create_plan_recurse(root, inner_path,
(best_path->innersortkeys != NIL) ? CP_SMALL_TLIST : 0);
/* Sort join qual clauses into best execution order */
@@ -3586,34 +3614,38 @@ create_mergejoin_plan(PlannerInfo *root,
* outer_is_left status.
*/
mergeclauses = get_switched_clauses(best_path->path_mergeclauses,
- best_path->jpath.outerjoinpath->parent->relids);
+ outer_path->parent->relids);
/*
* Create explicit sort nodes for the outer and inner paths if necessary.
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
outerpathkeys = best_path->outersortkeys;
}
else
- outerpathkeys = best_path->jpath.outerjoinpath->pathkeys;
+ outerpathkeys = outer_path->pathkeys;
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
innerpathkeys = best_path->innersortkeys;
}
else
- innerpathkeys = best_path->jpath.innerjoinpath->pathkeys;
+ innerpathkeys = inner_path->pathkeys;
/*
* If specified, add a materialize node to shield the inner plan from the
@@ -3951,6 +3983,215 @@ create_hashjoin_plan(PlannerInfo *root,
return join_plan;
}
+/*
+ * create_partition_join_plan
+ * Creates Merge/Append plan consisting of join plans for child-join.
+ *
+ * Returns a Plan node.
+ */
+static Plan *
+create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
+{
+ RelOptInfo *joinrel = best_path->path.parent;
+ int nparts;
+ int cnt_parts;
+ List *child_plans = NIL;
+ List *tlist = build_path_tlist(root, &best_path->path);
+ Plan *plan;
+ MemoryContext child_context;
+ MemoryContext old_context;
+ List *pathkeys = best_path->path.pathkeys;
+ StringInfoData mem_context_name;
+
+ /* The relation should be a partitioned join relation. */
+ Assert(IS_JOIN_REL(joinrel) && joinrel->part_scheme &&
+ joinrel->partitioned_joins);
+
+ nparts = joinrel->part_scheme->nparts;
+
+ /* Create MergeAppend plan when result is expected to be ordered. */
+ if (pathkeys)
+ {
+ MergeAppend *node = makeNode(MergeAppend);
+ plan = &node->plan;
+
+ plan->targetlist = tlist;
+
+ /* Compute sorting info, and adjust MergeAppend's tlist as needed. */
+ (void) prepare_sort_from_pathkeys(plan, pathkeys,
+ best_path->path.parent->relids,
+ NULL,
+ true,
+ &node->numCols,
+ &node->sortColIdx,
+ &node->sortOperators,
+ &node->collations,
+ &node->nullsFirst);
+ }
+ else
+ {
+ Append *node = makeNode(Append);
+ plan = &node->plan;
+ plan->targetlist = tlist;
+ }
+
+ /* Fill costs, so that we can cost Sort node, if required. */
+ copy_generic_path_info(plan, (Path *) best_path);
+
+ /*
+ * Create a new memory context for planning child joins. Since this routine
+ * may be called recursively for tables with subpartitions, we use
+ * a unique context name for every level of partition by using the lowest
+ * relid amongst the base relations being joined.
+ */
+ initStringInfo(&mem_context_name);
+ appendStringInfo(&mem_context_name, "%s_%d", "ChildJoinContext",
+ bms_next_member(joinrel->relids, -1));
+ child_context = AllocSetContextCreate(CurrentMemoryContext,
+ pstrdup(mem_context_name.data),
+ ALLOCSET_DEFAULT_SIZES);
+ pfree(mem_context_name.data);
+ resetStringInfo(&mem_context_name);
+
+ /*
+ * Create a paths for all child joins, one child join at a time. The paths
+ * for every child join are independent i.e. one child does not require
+ * paths created for the other. In order to avoid accumulating memory
+ * consumed while creating paths for every child join, we use a fresh
+ * memory context for every child join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_join;
+ Path *child_path = NULL;
+ Plan *child_plan;
+ int numsortkeys;
+ AttrNumber *sortColIdx;
+ Oid *sortOperators;
+ Oid *collations;
+ bool *nullsFirst;
+
+ /*
+ * Create paths for the child join in a separate context, so that we
+ * can reuse the memory used by those paths.
+ */
+ old_context = MemoryContextSwitchTo(child_context);
+
+ add_paths_to_child_joinrel(root, joinrel, cnt_parts);
+
+ child_join = joinrel->part_rels[cnt_parts];
+
+
+ /* Skip empty child. */
+ if (IS_DUMMY_REL(child_join))
+ {
+ MemoryContextSwitchTo(old_context);
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ /*
+ * Search for a child path with pathkeys or parameterization
+ * matching that of the given path.
+ */
+ child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
+ best_path->path.pathkeys,
+ PATH_REQ_OUTER(&best_path->path),
+ TOTAL_COST);
+
+ if (!child_path)
+ elog(ERROR, "Could not find a path with required pathkeys.");
+
+ MemoryContextSwitchTo(old_context);
+
+ /* Create plan for the current child. */
+ child_plan = create_plan_recurse(root, child_path, CP_EXACT_TLIST);
+
+ if (pathkeys)
+ {
+ MergeAppend *node = (MergeAppend *) plan;
+
+ Assert(IsA(node, MergeAppend));
+
+ /* Compute sorting info, and adjust subplan's tlist as needed */
+ child_plan = prepare_sort_from_pathkeys(child_plan, pathkeys,
+ child_path->parent->relids,
+ node->sortColIdx,
+ false,
+ &numsortkeys,
+ &sortColIdx,
+ &sortOperators,
+ &collations,
+ &nullsFirst);
+
+ /*
+ * Check that we got the same sort key information. We just Assert
+ * that the sortops match, since those depend only on the pathkeys;
+ * but it seems like a good idea to check the sort column numbers
+ * explicitly, to ensure the tlists really do match up.
+ */
+ Assert(numsortkeys == node->numCols);
+ if (memcmp(sortColIdx, node->sortColIdx,
+ numsortkeys * sizeof(AttrNumber)) != 0)
+ elog(ERROR, "MergeAppend child's targetlist doesn't match MergeAppend");
+ Assert(memcmp(sortOperators, node->sortOperators,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(collations, node->collations,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(nullsFirst, node->nullsFirst,
+ numsortkeys * sizeof(bool)) == 0);
+
+ /* Now, insert a Sort node if subplan isn't sufficiently ordered */
+ if (!pathkeys_contained_in(pathkeys, child_path->pathkeys))
+ {
+ Sort *sort = make_sort(child_plan, numsortkeys,
+ sortColIdx, sortOperators,
+ collations, nullsFirst);
+ label_sort_with_costsize(root, sort, -1.0);
+ child_plan = (Plan *) sort;
+ }
+ }
+
+ child_plans = lappend(child_plans, child_plan);
+
+ /*
+ * Reset the child_join memory context to reclaim the memory consumed
+ * while creating paths.
+ */
+ MemoryContextResetAndDeleteChildren(child_context);
+ }
+
+ /* Destroy the child context as we do not need it anymore. */
+ Assert(CurrentMemoryContext == old_context);
+ MemoryContextDelete(child_context);
+
+ /* Partitioned relation with all empty children gets a dummy path. */
+ Assert(child_plans != NIL);
+
+ if (IsA(plan, MergeAppend))
+ {
+ MergeAppend *node = (MergeAppend *)plan;
+
+ node->mergeplans = child_plans;
+ }
+ else
+ {
+ Append *node = (Append *)plan;
+
+ Assert(IsA(plan, Append));
+ node->appendplans = child_plans;
+ }
+
+ /* Complete rest of the plan. */
+ plan->qual = NIL;
+ plan->lefttree = NULL;
+ plan->righttree = NULL;
+ return plan;
+}
+
/*****************************************************************************
*
@@ -4009,6 +4250,7 @@ replace_nestloop_params_mutator(Node *node, PlannerInfo *root)
nlp->paramno = param->paramid;
nlp->paramval = var;
root->curOuterParams = lappend(root->curOuterParams, nlp);
+
/* And return the replacement Param */
return (Node *) param;
}
@@ -4072,6 +4314,7 @@ replace_nestloop_params_mutator(Node *node, PlannerInfo *root)
nlp->paramno = param->paramid;
nlp->paramval = (Var *) phv;
root->curOuterParams = lappend(root->curOuterParams, nlp);
+
/* And return the replacement Param */
return (Node *) param;
}
@@ -5343,11 +5586,11 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
@@ -5458,10 +5701,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
@@ -5482,9 +5725,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
@@ -5494,7 +5738,7 @@ make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 41dde50..fedbb43 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -1105,7 +1105,7 @@ inheritance_planner(PlannerInfo *root)
subroot->parse = (Query *)
adjust_appendrel_attrs(root,
(Node *) parse,
- appinfo);
+ list_make1(appinfo));
/*
* The rowMarks list might contain references to subquery RTEs, so
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index b714783..8b6a183 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -55,7 +55,7 @@
typedef struct
{
PlannerInfo *root;
- AppendRelInfo *appinfo;
+ List *appinfos;
int sublevels_up;
} adjust_appendrel_attrs_context;
@@ -108,7 +108,6 @@ static Bitmapset *translate_col_privs(const Bitmapset *parent_privs,
List *translated_vars);
static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
-static Relids adjust_relid_set(Relids relids, Index oldrelid, Index newrelid);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
@@ -1712,10 +1711,10 @@ translate_col_privs(const Bitmapset *parent_privs,
/*
* adjust_appendrel_attrs
- * Copy the specified query or expression and translate Vars referring
- * to the parent rel of the specified AppendRelInfo to refer to the
- * child rel instead. We also update rtindexes appearing outside Vars,
- * such as resultRelation and jointree relids.
+ * Copy the specified query or expression and translate Vars referring to
+ * the parent rels specified in the given list of AppendRelInfos to refer to
+ * the corresponding child rels instead. We also update rtindexes appearing
+ * outside Vars, such as resultRelation and jointree relids.
*
* Note: this is applied after conversion of sublinks to subplans in the
* query jointree, but there may still be sublinks in the security barrier
@@ -1725,15 +1724,18 @@ translate_col_privs(const Bitmapset *parent_privs,
* maybe we should try to fold the two routines together.
*/
Node *
-adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
+adjust_appendrel_attrs(PlannerInfo *root, Node *node, List *appinfos)
{
Node *result;
adjust_appendrel_attrs_context context;
+ ListCell *lc;
context.root = root;
- context.appinfo = appinfo;
+ context.appinfos = appinfos;
context.sublevels_up = 0;
+ Assert(appinfos && list_length(appinfos) >= 1);
+
/*
* Must be prepared to start with a Query or a bare expression tree; if
* it's a Query, go straight to query_tree_walker to make sure that
@@ -1742,11 +1744,20 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
if (node && IsA(node, Query))
{
Query *newnode;
+ AppendRelInfo *appinfo;
newnode = query_tree_mutator((Query *) node,
adjust_appendrel_attrs_mutator,
(void *) &context,
QTW_IGNORE_RC_SUBQUERIES);
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (newnode->resultRelation == appinfo->parent_relid)
+ break;
+ }
+
if (newnode->resultRelation == appinfo->parent_relid)
{
newnode->resultRelation = appinfo->child_relid;
@@ -1764,17 +1775,51 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
return result;
}
+/*
+ * find_appinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *appinfo_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (bms_is_member(appinfo->child_relid, relids))
+ appinfo_list = lappend(appinfo_list, appinfo);
+ }
+
+ Assert(list_length(appinfo_list) == bms_num_members(relids));
+ return appinfo_list;
+}
+
static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
- AppendRelInfo *appinfo = context->appinfo;
+ List *appinfos = context->appinfos;
+ ListCell *lc;
+
+ Assert(appinfos && list_length(appinfos) >= 1);
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
Var *var = (Var *) copyObject(node);
+ AppendRelInfo *appinfo;
+
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (var->varno == appinfo->parent_relid)
+ break;
+ }
if (var->varlevelsup == context->sublevels_up &&
var->varno == appinfo->parent_relid)
@@ -1865,32 +1910,58 @@ adjust_appendrel_attrs_mutator(Node *node,
{
CurrentOfExpr *cexpr = (CurrentOfExpr *) copyObject(node);
- if (context->sublevels_up == 0 &&
- cexpr->cvarno == appinfo->parent_relid)
- cexpr->cvarno = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ cexpr->cvarno == appinfo->parent_relid)
+ {
+ cexpr->cvarno = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) cexpr;
}
if (IsA(node, RangeTblRef))
{
RangeTblRef *rtr = (RangeTblRef *) copyObject(node);
- if (context->sublevels_up == 0 &&
- rtr->rtindex == appinfo->parent_relid)
- rtr->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ rtr->rtindex == appinfo->parent_relid)
+ {
+ rtr->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) rtr;
}
if (IsA(node, JoinExpr))
{
/* Copy the JoinExpr node with correct mutation of subnodes */
JoinExpr *j;
+ AppendRelInfo *appinfo;
j = (JoinExpr *) expression_tree_mutator(node,
adjust_appendrel_attrs_mutator,
(void *) context);
+
/* now fix JoinExpr's rtindex (probably never happens) */
- if (context->sublevels_up == 0 &&
- j->rtindex == appinfo->parent_relid)
- j->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (context->sublevels_up == 0 &&
+ j->rtindex == appinfo->parent_relid)
+ {
+ j->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) j;
}
if (IsA(node, PlaceHolderVar))
@@ -1903,9 +1974,8 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == context->sublevels_up)
- phv->phrels = adjust_relid_set(phv->phrels,
- appinfo->parent_relid,
- appinfo->child_relid);
+ phv->phrels = adjust_child_relids(phv->phrels, context->appinfos);
+
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1936,24 +2006,18 @@ adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_mutator((Node *) oldinfo->orclause, context);
/* adjust relid sets too */
- newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
- newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ newinfo->clause_relids = adjust_child_relids(oldinfo->clause_relids,
+ context->appinfos);
+ newinfo->required_relids = adjust_child_relids(oldinfo->required_relids,
+ context->appinfos);
+ newinfo->outer_relids = adjust_child_relids(oldinfo->outer_relids,
+ context->appinfos);
+ newinfo->nullable_relids = adjust_child_relids(oldinfo->nullable_relids,
+ context->appinfos);
+ newinfo->left_relids = adjust_child_relids(oldinfo->left_relids,
+ context->appinfos);
+ newinfo->right_relids = adjust_child_relids(oldinfo->right_relids,
+ context->appinfos);
/*
* Reset cached derivative fields, since these might need to have
@@ -2002,23 +2066,6 @@ adjust_appendrel_attrs_mutator(Node *node,
}
/*
- * Substitute newrelid for oldrelid in a Relid set
- */
-static Relids
-adjust_relid_set(Relids relids, Index oldrelid, Index newrelid)
-{
- if (bms_is_member(oldrelid, relids))
- {
- /* Ensure we have a modifiable copy */
- relids = bms_copy(relids);
- /* Remove old, add new */
- relids = bms_del_member(relids, oldrelid);
- relids = bms_add_member(relids, newrelid);
- }
- return relids;
-}
-
-/*
* Adjust the targetlist entries of an inherited UPDATE operation
*
* The expressions have already been fixed, but we have to make sure that
@@ -2135,5 +2182,100 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
else
Assert(parent_rel->reloptkind == RELOPT_BASEREL);
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, appinfo);
+ return adjust_appendrel_attrs(root, node, list_make1(appinfo));
+}
+
+/*
+ * build_child_restrictinfo
+ * Returns a RestrictInfo which is derived from the given RestrictInfo by
+ * applying the parent-child translation specified by the list of
+ * AppendRelInfos.
+ *
+ * The topmost parent's RestrictInfo maintains a list of child RestrictInfos
+ * derived from it. If a suitable RestrictInfo is found in that list, it is
+ * returned as is. If there is no such child RestrictInfo, we translate the given
+ * RestrictInfo using the given list of AppendRelInfos and stick it in the
+ * topmost parent's list before returning it to the caller.
+ */
+RestrictInfo *
+build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
+ List *append_rel_infos)
+{
+ Relids child_required_relids;
+ ListCell *lc;
+ RestrictInfo *parent_rinfo;
+ RestrictInfo *child_rinfo;
+ MemoryContext old_context;
+
+ child_required_relids = adjust_child_relids(rinfo->required_relids,
+ append_rel_infos);
+
+
+ /* Nothing to do, if the clause does not need any translation. */
+ if (bms_equal(child_required_relids, rinfo->required_relids))
+ {
+ bms_free(child_required_relids);
+ return rinfo;
+ }
+
+ /*
+ * Check if we already have the RestrictInfo for the given child in the
+ * topmost parent's RestrictInfo.
+ */
+ parent_rinfo = rinfo->parent_rinfo ? rinfo->parent_rinfo : rinfo;
+ foreach (lc, parent_rinfo->child_rinfos)
+ {
+ child_rinfo = lfirst(lc);
+
+ if (bms_equal(child_rinfo->required_relids, child_required_relids))
+ {
+ bms_free(child_required_relids);
+ return child_rinfo;
+ }
+ }
+
+ /*
+ * We didn't find any child restrictinfo for the given child, translate the
+ * given RestrictInfo and stick it into the parent's list. The clause
+ * expression may get used in plan, so create the child RestrictInfo in the
+ * planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ child_rinfo = (RestrictInfo *) adjust_appendrel_attrs(root, (Node *) rinfo,
+ append_rel_infos);
+ bms_free(child_required_relids);
+ parent_rinfo->child_rinfos = lappend(parent_rinfo->child_rinfos,
+ child_rinfo);
+ child_rinfo->parent_rinfo = parent_rinfo;
+
+ MemoryContextSwitchTo(old_context);
+
+ return child_rinfo;
+}
+
+/*
+ * build_child_clauses
+ * Convenience routine to call build_child_restrictinfo on a list of
+ * clauses.
+ */
+List *
+build_child_clauses(PlannerInfo *root, List *clauses, List *append_rel_infos)
+{
+ List *child_clauses = NIL;
+ ListCell *lc;
+
+ foreach (lc, clauses)
+ {
+ RestrictInfo *parent_rinfo = lfirst(lc);
+ RestrictInfo *child_rinfo;
+
+ Assert(IsA(parent_rinfo, RestrictInfo));
+
+ child_rinfo = build_child_restrictinfo(root, parent_rinfo,
+ append_rel_infos);
+
+ child_clauses = lappend(child_clauses, child_rinfo);
+ }
+
+ return child_clauses;
}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index 6d3ccfd..f5010e4 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -23,7 +23,9 @@
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
@@ -2154,6 +2156,176 @@ create_hashjoin_path(PlannerInfo *root,
}
/*
+ * create_partition_join_path
+ * Creates a pathnode that represents partition-wise join for given
+ * partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the cost of representative child-joins
+ * paths.
+ */
+PartitionJoinPath *
+create_partition_join_path(RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = T_Append;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = NULL;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+ subpath_total_cost += subpath->total_cost;
+
+ /*
+ * Startup cost of an append relation is the startup cost of the first
+ * subpath. Assume that the given first child will be the first child
+ * in the final plan as well.
+ */
+ if (lc == list_head(subpaths))
+ subpath_startup_cost = subpath->startup_cost;
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ pathnode->path.startup_cost = subpath_startup_cost;
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ /*
+ * Multiply the costs with scaling factor as specified. Used to encourage
+ * or discourage use of partition-wise join plans.
+ */
+ pathnode->path.startup_cost *= partition_wise_plan_weight;
+ pathnode->path.total_cost *= partition_wise_plan_weight;
+
+ return pathnode;
+}
+
+/*
+ * create_partition_join_path_with_pathkeys
+ * Creates a pathnode that represents an ordered partition-wise join for
+ * given partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the cost of representative child-joins
+ * paths.
+ */
+PartitionJoinPath *
+create_partition_join_path_with_pathkeys(PlannerInfo *root, RelOptInfo *rel,
+ List *subpaths, List *pathkeys,
+ Bitmapset *required_outer)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = T_MergeAppend;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = pathkeys;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ if (pathkeys_contained_in(pathkeys, subpath->pathkeys))
+ {
+ /* Subpath is adequately ordered, we won't need to sort it */
+ subpath_startup_cost += subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else
+ {
+ /* We'll need to insert a Sort node, so include cost for that */
+ Path sort_path; /* dummy for result of cost_sort */
+
+ cost_sort(&sort_path,
+ root,
+ pathkeys,
+ subpath->total_cost,
+ subpath->parent->tuples,
+ subpath->pathtarget->width,
+ 0.0,
+ work_mem,
+ -1);
+ subpath_startup_cost += sort_path.startup_cost;
+ subpath_total_cost += sort_path.total_cost;
+ }
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ pathnode->path.startup_cost = (subpath_startup_cost * pathnode->path.rows) / subpath_rows;
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ /*
+ * Multiply the costs with scaling factor as specified. Used to encourage
+ * or discourage use of partition-wise join plans.
+ */
+ pathnode->path.startup_cost *= partition_wise_plan_weight;
+ pathnode->path.total_cost *= partition_wise_plan_weight;
+
+ return pathnode;
+}
+/*
* create_projection_path
* Creates a pathnode that represents performing a projection.
*
@@ -3209,3 +3381,183 @@ reparameterize_path(PlannerInfo *root, Path *path,
}
return NULL;
}
+
+/*
+ * reparameterize_path_by_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ *
+ * The cost, number of rows, width and parallel path properties depend upon
+ * path->parent, which does not change during the translation. Hence those
+ * members are copied as they are.
+ */
+
+Path *
+reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+ Relids required_outer;
+
+ /*
+ * If the path is not parameterized by parent of the given relation or it it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ required_outer = adjust_child_relids(old_ppi->ppi_req_outer, child_aris);
+
+ /* If we already have a PPI for this parameterization, just return it */
+ new_ppi = find_param_path_info(new_path->parent, required_outer);
+
+ /* If not build a new one and link it to the list of PPIs. */
+ if (!new_ppi)
+ {
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = required_outer;
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = build_child_clauses(root, old_ppi->ppi_clauses,
+ child_aris);
+ new_path->parent->ppilist = lappend(new_path->parent->ppilist, new_ppi);
+ }
+ else
+ bms_free(required_outer);
+
+ new_path->param_info = new_ppi;
+
+ /*
+ * Adjust the path target if the parent of the outer relation is referenced
+ * in the targetlist. This can happen when only the parent of outer relation is
+ * laterally referenced in this relation.
+ */
+ if (bms_overlap(path->parent->lateral_relids, child_rel->top_parent_relids))
+ {
+ MemoryContext old_context;
+
+ /*
+ * Allocate the target in planner's context, since they are copies as
+ * is from path while creating plans.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ MemoryContextSwitchTo(old_context);
+ }
+
+ /*
+ * Change parameterization of subpaths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_by_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_by_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = build_child_clauses(root,
+ jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_by_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexclauses = build_child_clauses(root, ipath->indexclauses,
+ child_aris);
+ ipath->indexquals = build_child_clauses(root, ipath->indexquals,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/placeholder.c b/src/backend/optimizer/util/placeholder.c
index b210914..b67c62f 100644
--- a/src/backend/optimizer/util/placeholder.c
+++ b/src/backend/optimizer/util/placeholder.c
@@ -21,6 +21,7 @@
#include "optimizer/placeholder.h"
#include "optimizer/planmain.h"
#include "optimizer/var.h"
+#include "optimizer/prep.h"
#include "utils/lsyscache.h"
/* Local functions */
@@ -414,6 +415,10 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
Relids relids = joinrel->relids;
ListCell *lc;
+ /* This function is called only on the parent relations. */
+ Assert(!IS_OTHER_REL(joinrel) && !IS_OTHER_REL(outer_rel) &&
+ !IS_OTHER_REL(inner_rel));
+
foreach(lc, root->placeholder_list)
{
PlaceHolderInfo *phinfo = (PlaceHolderInfo *) lfirst(lc);
@@ -424,9 +429,11 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
/* Is it computable here? */
if (bms_is_subset(phinfo->ph_eval_at, relids))
{
+ PlaceHolderVar *phv = phinfo->ph_var;
+
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs,
- phinfo->ph_var);
+ phv);
joinrel->reltarget->width += phinfo->ph_width;
/*
@@ -445,7 +452,7 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
{
QualCost cost;
- cost_qual_eval_node(&cost, (Node *) phinfo->ph_var->phexpr,
+ cost_qual_eval_node(&cost, (Node *) phv->phexpr,
root);
joinrel->reltarget->cost.startup += cost.startup;
joinrel->reltarget->cost.per_tuple += cost.per_tuple;
@@ -459,3 +466,53 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
}
}
}
+
+/*
+ * add_placeholders_to_child_joinrel
+ * Translate the PHVs in parent's targetlist and add them to the child's
+ * targetlist. Also adjust the cost
+ */
+void
+add_placeholders_to_child_joinrel(PlannerInfo *root, RelOptInfo *childrel,
+ RelOptInfo *parentrel)
+{
+ ListCell *lc;
+
+ /* This function is called only for join relations. */
+ Assert(IS_JOIN_REL(childrel) && IS_JOIN_REL(parentrel));
+
+ /* Ensure child relations is really what it claims to be. */
+ Assert(IS_OTHER_REL(childrel));
+
+ foreach (lc, parentrel->reltarget->exprs)
+ {
+ PlaceHolderVar *phv = lfirst(lc);
+
+ if (IsA(phv, PlaceHolderVar))
+ {
+ /*
+ * In case the placeholder Var refers to any of the parent
+ * relations, translate it to refer to the corresponding child.
+ */
+ if (bms_overlap(phv->phrels, parentrel->relids) &&
+ childrel->reloptkind == RELOPT_OTHER_JOINREL)
+ {
+ List *append_rel_infos;
+
+ append_rel_infos = find_appinfos_by_relids(root,
+ childrel->relids);
+ phv = (PlaceHolderVar *) adjust_appendrel_attrs(root,
+ (Node *) phv,
+ append_rel_infos);
+ }
+
+ childrel->reltarget->exprs = lappend(childrel->reltarget->exprs,
+ phv);
+ }
+ }
+
+ /* Adjust the cost and width of child targetlist. */
+ childrel->reltarget->cost.startup = parentrel->reltarget->cost.startup;
+ childrel->reltarget->cost.per_tuple = parentrel->reltarget->cost.per_tuple;
+ childrel->reltarget->width = parentrel->reltarget->width;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 72272d9..88e66e4 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -412,6 +412,21 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation, inhparent);
+ /*
+ * Lookup partition scheme for the given relation. Only parent relations
+ * can be partitioned.
+ */
+ if (inhparent)
+ rel->part_scheme = find_partition_scheme(root, relation);
+ else
+ rel->part_scheme = NULL;
+
+ if (rel->part_scheme)
+ rel->partexprs = build_baserel_partition_key_exprs(relation,
+ rel->relid);
+ else
+ rel->partexprs = NULL;
+
heap_close(relation, NoLock);
/*
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index d5326e6..a9a707f 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -15,15 +15,22 @@
#include "postgres.h"
#include "miscadmin.h"
+#include "catalog/heap.h"
+#include "catalog/partition.h"
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
+#include "nodes/makefuncs.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
+#include "optimizer/var.h"
+#include "rewrite/rewriteManip.h"
#include "utils/hsearch.h"
+#include "utils/rel.h"
typedef struct JoinHashEntry
@@ -34,10 +41,6 @@ typedef struct JoinHashEntry
static void build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel);
-static List *build_joinrel_restrictlist(PlannerInfo *root,
- RelOptInfo *joinrel,
- RelOptInfo *outer_rel,
- RelOptInfo *inner_rel);
static void build_joinrel_joinlist(RelOptInfo *joinrel,
RelOptInfo *outer_rel,
RelOptInfo *inner_rel);
@@ -47,6 +50,11 @@ static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
/*
@@ -137,6 +145,10 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptKind reloptkind)
rel->baserestrictcost.per_tuple = 0;
rel->joininfo = NIL;
rel->has_eclass_joins = false;
+ rel->part_scheme = NULL;
+ rel->partexprs = NULL;
+ rel->top_parent_relids = NULL;
+ rel->part_rels = NULL;
/* Check type of rtable entry */
switch (rte->rtekind)
@@ -314,6 +326,56 @@ find_join_rel(PlannerInfo *root, Relids relids)
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
@@ -363,7 +425,11 @@ build_join_rel(PlannerInfo *root,
* Nope, so make one.
*/
joinrel = makeNode(RelOptInfo);
+
+ Assert(!IS_OTHER_REL(outer_rel) && !IS_OTHER_REL(inner_rel));
+
joinrel->reloptkind = RELOPT_JOINREL;
+
joinrel->relids = bms_copy(joinrelids);
joinrel->rows = 0;
/* cheap startup cost is interesting iff not all tuples to be retrieved */
@@ -409,47 +475,13 @@ build_join_rel(PlannerInfo *root,
joinrel->baserestrictcost.per_tuple = 0;
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Compute information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
@@ -475,6 +507,10 @@ build_join_rel(PlannerInfo *root,
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
@@ -517,25 +553,8 @@ build_join_rel(PlannerInfo *root,
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the query's PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
@@ -555,6 +574,127 @@ build_join_rel(PlannerInfo *root,
}
/*
+ * build_child_join_rel
+ * Builds RelOptInfo for joining given two child relations from RelOptInfo
+ * representing the join between their parents.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of child relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for child join
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_appinfos': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ JoinType jointype)
+{
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel) && IS_OTHER_REL(inner_rel));
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Compute information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /* Build targetlist */
+ build_joinrel_tlist(root, joinrel, outer_rel);
+ build_joinrel_tlist(root, joinrel, inner_rel);
+ /* Add placeholder variables. */
+ add_placeholders_to_child_joinrel(root, joinrel, parent_joinrel);
+
+ /* Construct joininfo list. */
+ joinrel->joininfo = build_child_clauses(root, parent_joinrel->joininfo,
+ find_appinfos_by_relids(root,
+ joinrel->relids));
+
+ /*
+ * Lateral relids referred in child join will be same as that referred in
+ * the parent relation. Throw any partial result computed while building
+ * the targetlist.
+ */
+ bms_free(joinrel->direct_lateral_relids);
+ bms_free(joinrel->lateral_relids);
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, jointype);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ /* We build the join only once. */
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
+/*
* min_join_parameterization
*
* Determine the minimum possible parameterization of a joinrel, that is, the
@@ -609,9 +749,15 @@ static void
build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *vars;
+ /* attrs_needed refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(vars, input_rel->reltarget->exprs)
{
Var *var = (Var *) lfirst(vars);
@@ -627,23 +773,47 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
/*
* Otherwise, anything in a baserel or joinrel targetlist ought to be
- * a Var. (More general cases can only appear in appendrel child
- * rels, which will never be seen here.)
+ * a Var or ConvertRowtypeExpr introduced while translating parent
+ * targetlist to that of the child.
*/
- if (!IsA(var, Var))
+ if (IsA(var, Var))
+ {
+ /* Get the Var's original base rel */
+ baserel = find_base_rel(root, var->varno);
+
+ /* Is it still needed above this joinrel? */
+ ndx = var->varattno - baserel->min_attr;
+ }
+ else if (IsA(var, ConvertRowtypeExpr))
+ {
+ ConvertRowtypeExpr *child_expr = (ConvertRowtypeExpr *) var;
+ Var *childvar = (Var *) child_expr->arg;
+
+ /*
+ * Child's whole-row references are converted to that of parent
+ * using ConvertRowtypeExpr. In this case, the argument to
+ * ConvertRowtypeExpr is expected to be a whole-row reference of
+ * the child.
+ */
+ Assert(IsA(childvar, Var) && childvar->varattno == 0);
+
+ baserel = find_base_rel(root, childvar->varno);
+ ndx = 0 - baserel->min_attr;
+ }
+ else
elog(ERROR, "unexpected node type in rel targetlist: %d",
(int) nodeTag(var));
- /* Get the Var's original base rel */
- baserel = find_base_rel(root, var->varno);
-
- /* Is it still needed above this joinrel? */
- ndx = var->varattno - baserel->min_attr;
if (bms_nonempty_difference(baserel->attr_needed[ndx], relids))
{
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs, var);
- /* Vars have cost zero, so no need to adjust reltarget->cost */
+
+ /*
+ * Vars have cost zero, so no need to adjust reltarget->cost. Even
+ * if, it's a ConvertRowtypeExpr, it will be computed only for the
+ * base relation, costing nothing for a join.
+ */
joinrel->reltarget->width += baserel->attr_widths[ndx];
}
}
@@ -691,7 +861,7 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
* RestrictInfo nodes are no longer context-dependent. Instead, just include
* the original nodes in the lists made for the join relation.
*/
-static List *
+List *
build_joinrel_restrictlist(PlannerInfo *root,
RelOptInfo *joinrel,
RelOptInfo *outer_rel,
@@ -780,6 +950,8 @@ subbuild_joinrel_joinlist(RelOptInfo *joinrel,
{
ListCell *l;
+ Assert(joinrel->reloptkind == RELOPT_JOINREL);
+
foreach(l, joininfo_list)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(l);
@@ -808,7 +980,6 @@ subbuild_joinrel_joinlist(RelOptInfo *joinrel,
return new_joininfo;
}
-
/*
* build_empty_join_rel
* Build a dummy join relation describing an empty set of base rels.
@@ -933,9 +1104,17 @@ find_childrel_appendrelinfo(PlannerInfo *root, RelOptInfo *rel)
* appendrel ancestors. This function locates the topmost ancestor,
* which will be a regular baserel not an otherrel.
*/
-RelOptInfo *
+Relids
find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel)
{
+ Assert(IS_OTHER_REL(rel));
+
+ /* Child-join relations cache this in their RelOptInfo. */
+ if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ return rel->top_parent_relids;
+
+ Assert(rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
do
{
AppendRelInfo *appinfo = find_childrel_appendrelinfo(root, rel);
@@ -947,7 +1126,7 @@ find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel)
Assert(rel->reloptkind == RELOPT_BASEREL);
- return rel;
+ return rel->relids;
}
@@ -1009,12 +1188,8 @@ get_baserel_parampathinfo(PlannerInfo *root, RelOptInfo *baserel,
Assert(!bms_overlap(baserel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, baserel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(baserel, required_outer)))
+ return ppi;
/*
* Identify all joinclauses that are movable to this base rel given this
@@ -1251,12 +1426,8 @@ get_joinrel_parampathinfo(PlannerInfo *root, RelOptInfo *joinrel,
*restrict_clauses = list_concat(pclauses, *restrict_clauses);
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, joinrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(joinrel, required_outer)))
+ return ppi;
/* Estimate the number of rows returned by the parameterized join */
rows = get_parameterized_joinrel_size(root, joinrel,
@@ -1295,7 +1466,6 @@ ParamPathInfo *
get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
{
ParamPathInfo *ppi;
- ListCell *lc;
/* Unparameterized paths have no ParamPathInfo */
if (bms_is_empty(required_outer))
@@ -1304,12 +1474,8 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
Assert(!bms_overlap(appendrel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, appendrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(appendrel, required_outer)))
+ return ppi;
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
@@ -1320,3 +1486,130 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
return ppi;
}
+
+/*
+ * add_join_rel
+ * Add given join relation to the list of join relations in the given
+ * PlannerInfo. Also add it to the auxiliary hashtable if there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
+ * build_joinrel_partition_info
+ * If the join between given partitioned relations is possibly partitioned
+ * set the partitioning scheme and partition keys expressions for the
+ * join.
+ *
+ * If the two relations have same partitioning scheme, their join may be
+ * partitioned and will follow the same partitioning scheme as the joining
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /* Nothing to do if partition-wise join technique is disabled. */
+ if (!enable_partition_wise_join)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * The join is not partitioned, if any of the relations being joined are
+ * not partitioned or they do not have same partitioning scheme.
+ */
+ if (!outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel, hence it should
+ * not have partition scheme, partition key expressions and array for
+ * storing child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ /*
+ * Join relation is partitioned using same partitioning scheme as the
+ * joining relations.
+ */
+ joinrel->part_scheme = outer_rel->part_scheme;
+ num_pks = joinrel->part_scheme->partnatts;
+
+ /*
+ * Construct partition keys for the join.
+ *
+ * An INNER join between two partitioned relations is partition by key
+ * expressions from both the relations. For tables A and B partitioned by a and b
+ * respectively, (A INNER JOIN B ON A.a = B.b) is partitioned by both A.a
+ * and B.b.
+ *
+ * An OUTER join like (A LEFT JOIN B ON A.a = B.b) may produce rows with
+ * B.b NULL. These rows may not fit the partitioning conditions imposed on
+ * B.b. Hence, strictly speaking, the join is not partitioned by B.b.
+ * Strictly speaking, partition keys of an OUTER join should include
+ * partition key expressions from the OUTER side only. Consider a join like
+ * (A LEFT JOIN B on (A.a = B.b) LEFT JOIN C ON B.b = C.c. If we do not
+ * include B.b as partition key expression for (AB), it prohibits us from
+ * using partition-wise join when joining (AB) with C as there is no
+ * equi-join between partition keys of joining relations. But two NULL
+ * values are never equal and no two rows from mis-matching partitions can
+ * join. Hence it's safe to include B.b as partition key expression for
+ * (AB), even though rows in (AB) are not strictly partitioned by B.b.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
+
+/*
+ * Returns a ParamPathInfo for outer relations specified by required_outer, if
+ * already available in the given rel. Returns NULL otherwise.
+ */
+ParamPathInfo *
+find_param_path_info(RelOptInfo *rel, Relids required_outer)
+{
+ ListCell *lc;
+
+ foreach(lc, rel->ppilist)
+ {
+ ParamPathInfo *ppi = (ParamPathInfo *) lfirst(lc);
+ if (bms_equal(ppi->ppi_req_outer, required_outer))
+ return ppi;
+ }
+
+ return NULL;
+}
diff --git a/src/backend/postmaster/startup.c b/src/backend/postmaster/startup.c
index a7ae7e3..6787df6 100644
--- a/src/backend/postmaster/startup.c
+++ b/src/backend/postmaster/startup.c
@@ -169,7 +169,6 @@ HandleStartupProcInterrupts(void)
exit(1);
}
-
/* ----------------------------------
* Startup Process main entry point
* ----------------------------------
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index 4973396..713e361 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3426,7 +3426,9 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+
if (rel->tuples > 0)
{
/*
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 946ba9e..f3d40a1 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -893,6 +893,15 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
@@ -2927,6 +2936,16 @@ static struct config_real ConfigureNamesReal[] =
},
{
+ {"partition_wise_plan_weight", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Multiplication factor for partition-wise plan costs."),
+ NULL
+ },
+ &partition_wise_plan_weight,
+ DEFAULT_PARTITION_WISE_PLAN_WEIGHT, 0, DBL_MAX,
+ NULL, NULL, NULL
+ },
+
+ {
{"bgwriter_lru_multiplier", PGC_SIGHUP, RESOURCES_BGWRITER,
gettext_noop("Multiple of the average buffer usage to free per round."),
NULL
diff --git a/src/include/catalog/partition.h b/src/include/catalog/partition.h
index bf38df5..90c0179 100644
--- a/src/include/catalog/partition.h
+++ b/src/include/catalog/partition.h
@@ -70,6 +70,42 @@ typedef struct PartitionDispatchData
typedef struct PartitionDispatchData *PartitionDispatch;
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting may be partitioned in the same way as the underlying
+ * scan relations. All such relations partitioned in the same way share the
+ * partitioning scheme.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ PartitionBoundInfo boundinfo; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
+typedef struct PartitionSchemeData *PartitionScheme;
+
+/* Include here to avoid circular dependency with relation.h. */
+struct PlannerInfo;
+
extern void RelationBuildPartitionDesc(Relation relation);
extern bool partition_bounds_equal(PartitionKey key,
PartitionBoundInfo p1, PartitionBoundInfo p2);
@@ -87,4 +123,9 @@ extern int get_partition_for_tuple(PartitionDispatch *pd,
TupleTableSlot *slot,
EState *estate,
Oid *failed_at);
+extern List **build_baserel_partition_key_exprs(Relation relation,
+ Index varno);
+extern PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+
#endif /* PARTITION_H */
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 201f248..42775d0 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -238,6 +238,7 @@ typedef enum NodeTag
T_NestPath,
T_MergePath,
T_HashPath,
+ T_PartitionJoinPath,
T_AppendPath,
T_MergeAppendPath,
T_ResultPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 3a1255a..df5b60f 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -15,6 +15,7 @@
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
@@ -263,6 +264,9 @@ typedef struct PlannerInfo
List *initial_rels; /* RelOptInfos we are now trying to join */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
/* Use fetch_upper_rel() to get any particular upper rel */
List *upper_rels[UPPERREL_FINAL + 1]; /* upper-rel RelOptInfos */
@@ -352,6 +356,11 @@ typedef struct PlannerInfo
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing joins between child relations of
+ * different partitioned tables. These relations are not added to
+ * join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
@@ -471,10 +480,19 @@ typedef enum RelOptKind
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(rel) \
+ ((rel)->reloptkind == RELOPT_OTHER_MEMBER_REL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
+#define IS_JOIN_REL(rel) \
+ ((rel)->reloptkind == RELOPT_JOINREL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
@@ -542,6 +560,27 @@ typedef struct RelOptInfo
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For partitioned relations. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there may be as many elements
+ * as the number of joining
+ * relations.
+ */
+ List *partitioned_joins; /* List of join orders which yield
+ * relations partitioned by above
+ * partition scheme.
+ */
+
+ /* Set only for "other" base or join relations. */
+ Relids top_parent_relids; /* Relids of topmost parents. */
} RelOptInfo;
/*
@@ -1469,6 +1508,14 @@ typedef struct LimitPath
Node *limitCount; /* COUNT parameter, or NULL if none */
} LimitPath;
+/*
+ * PartitionJoinPath represents partition-wise join between two partitioned
+ * tables.
+ */
+typedef struct PartitionJoinPath
+{
+ Path path;
+} PartitionJoinPath;
/*
* Restriction clause info.
@@ -1663,6 +1710,12 @@ typedef struct RestrictInfo
/* cache space for hashclause processing; -1 if not yet set */
Selectivity left_bucketsize; /* avg bucketsize of left side */
Selectivity right_bucketsize; /* avg bucketsize of right side */
+
+ /* Only one of these two can be set. */
+ List *child_rinfos; /* RestrictInfos derived for children. */
+ struct RestrictInfo *parent_rinfo; /* Parent restrictinfo this
+ * RestrictInf is derived from.
+ */
} RestrictInfo;
/*
@@ -1785,6 +1838,21 @@ typedef struct SpecialJoinInfo
} SpecialJoinInfo;
/*
+ * Partitioned join information
+ *
+ * Saves information about relations which can be joined partition-wise and
+ * thus produce result which is partitioned by the partition scheme of the
+ * relation.
+ */
+typedef struct PartitionedJoin
+{
+ RelOptInfo *rel1;
+ RelOptInfo *rel2;
+ SpecialJoinInfo *sjinfo; /* SpecialJoinInfo applicable. */
+ List *restrictlist; /* applicable join clauses. */
+} PartitionedJoin;
+
+/*
* Append-relation info.
*
* When we expand an inheritable table or a UNION-ALL subselect into an
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 2a4df2f..aff7ab7 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -30,6 +30,7 @@
#define DEFAULT_PARALLEL_SETUP_COST 1000.0
#define DEFAULT_EFFECTIVE_CACHE_SIZE 524288 /* measured in pages */
+#define DEFAULT_PARTITION_WISE_PLAN_WEIGHT 1
typedef enum
{
@@ -66,7 +67,9 @@ extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
+extern double partition_wise_plan_weight;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 71d9154..d75d56f 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -225,10 +225,17 @@ extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
+extern PartitionJoinPath *create_partition_join_path(RelOptInfo *rel,
+ List *subpaths, Bitmapset *required_outer);
+extern PartitionJoinPath *create_partition_join_path_with_pathkeys(PlannerInfo *root,
+ RelOptInfo *rel, List *subpaths,
+ List *pathkeys, Bitmapset *required_outer);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
@@ -253,7 +260,7 @@ extern RelOptInfo *fetch_upper_rel(PlannerInfo *root, UpperRelationKind kind,
Relids relids);
extern AppendRelInfo *find_childrel_appendrelinfo(PlannerInfo *root,
RelOptInfo *rel);
-extern RelOptInfo *find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel);
+extern Relids find_childrel_top_parent(PlannerInfo *root, RelOptInfo *rel);
extern Relids find_childrel_parents(PlannerInfo *root, RelOptInfo *rel);
extern ParamPathInfo *get_baserel_parampathinfo(PlannerInfo *root,
RelOptInfo *baserel,
@@ -267,5 +274,15 @@ extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, JoinType jointype);
+extern List *build_joinrel_restrictlist(PlannerInfo *root,
+ RelOptInfo *joinrel,
+ RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel);
+extern void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 44abe83..5d7bcd9 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -53,6 +53,8 @@ extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
extern void generate_gather_paths(PlannerInfo *root, RelOptInfo *rel);
+extern void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
#ifdef OPTIMIZER_DEBUG
extern void debug_print_rel(PlannerInfo *root, RelOptInfo *rel);
@@ -104,6 +106,9 @@ extern bool have_join_order_restriction(PlannerInfo *root,
RelOptInfo *rel1, RelOptInfo *rel2);
extern bool have_dangerous_phv(PlannerInfo *root,
Relids outer_relids, Relids inner_params);
+extern void add_paths_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *parent_joinrel,
+ int child_id);
/*
* equivclass.c
@@ -219,4 +224,6 @@ extern PathKey *make_canonical_pathkey(PlannerInfo *root,
EquivalenceClass *eclass, Oid opfamily,
int strategy, bool nulls_first);
+extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
+
#endif /* PATHS_H */
diff --git a/src/include/optimizer/placeholder.h b/src/include/optimizer/placeholder.h
index 54d0216..1652eca 100644
--- a/src/include/optimizer/placeholder.h
+++ b/src/include/optimizer/placeholder.h
@@ -28,5 +28,7 @@ extern void fix_placeholder_input_needed_levels(PlannerInfo *root);
extern void add_placeholders_to_base_rels(PlannerInfo *root);
extern void add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+extern void add_placeholders_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *childrel, RelOptInfo *parentrel);
#endif /* PLACEHOLDER_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index fb35b68..2483303 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -28,6 +28,9 @@ extern void flatten_simple_union_all(PlannerInfo *root);
extern void reduce_outer_joins(PlannerInfo *root);
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
+extern Node *adjust_join_appendrel_attrs(PlannerInfo *root, Node *node,
+ List *append_rel_infos);
+extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
/*
* prototypes for prepqual.c
@@ -58,9 +61,13 @@ extern RelOptInfo *plan_set_operations(PlannerInfo *root);
extern void expand_inherited_tables(PlannerInfo *root);
extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
- AppendRelInfo *appinfo);
+ List *appinfos);
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
+extern RestrictInfo *build_child_restrictinfo(PlannerInfo *root,
+ RestrictInfo *rinfo, List *append_rel_infos);
+extern List *build_child_clauses(PlannerInfo *root, List *clauses,
+ List *append_rel_infos);
#endif /* PREP_H */
diff --git a/src/test/regress/expected/multi_level_partition_join.out b/src/test/regress/expected/multi_level_partition_join.out
new file mode 100644
index 0000000..d40ae55
--- /dev/null
+++ b/src/test/regress/expected/multi_level_partition_join.out
@@ -0,0 +1,458 @@
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Hash
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ Filter: ((t1_3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
+ Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Hash
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ Filter: ((t1_4.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
+ Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Hash
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ Filter: ((t1_5.a % 25) = 0)
+(64 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
+ -> Seq Scan on public.prt1_l_p1_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_l_p1_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.b = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text) AND ((t1_1.b + t1_1.a) = (t2_1.a + t2_1.b)))
+ -> Seq Scan on public.prt1_l_p1_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_l_p1_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.b = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text) AND ((t1_2.b + t1_2.a) = (t2_2.a + t2_2.b)))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_l_p2_p1 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
+ Hash Cond: ((t1_3.a = t2_3.b) AND (t1_3.b = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text) AND ((t1_3.b + t1_3.a) = (t2_3.a + t2_3.b)))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_3
+ Output: t1_3.a, t1_3.c, t1_3.b
+ -> Hash
+ Output: t2_3.b, t2_3.c, t2_3.a
+ -> Seq Scan on public.prt2_l_p2_p2 t2_3
+ Output: t2_3.b, t2_3.c, t2_3.a
+ Filter: ((t2_3.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_4.b, t2_4.c, t1_4.a, t1_4.c
+ Hash Cond: ((t1_4.a = t2_4.b) AND (t1_4.b = t2_4.a) AND ((t1_4.c)::text = (t2_4.c)::text) AND ((t1_4.b + t1_4.a) = (t2_4.a + t2_4.b)))
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c, t1_4.b
+ -> Hash
+ Output: t2_4.b, t2_4.c, t2_4.a
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c, t2_4.a
+ Filter: ((t2_4.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_5.b, t2_5.c, t1_5.a, t1_5.c
+ Hash Cond: ((t1_5.a = t2_5.b) AND (t1_5.b = t2_5.a) AND ((t1_5.c)::text = (t2_5.c)::text) AND ((t1_5.b + t1_5.a) = (t2_5.a + t2_5.b)))
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c, t1_5.b
+ -> Hash
+ Output: t2_5.b, t2_5.c, t2_5.a
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c, t2_5.a
+ Filter: ((t2_5.b % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Sort Key: prt1_l_p1_p1.a, prt2_l_p1_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
+ Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
+ -> Seq Scan on public.prt1_l_p1_p1
+ Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
+ Filter: ((prt1_l_p1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ -> Seq Scan on public.prt2_l_p1_p1
+ Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
+ Filter: ((prt2_l_p1_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt2_l_p1_p2.b, prt2_l_p1_p2.c
+ Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
+ -> Seq Scan on public.prt1_l_p1_p2
+ Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
+ Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ -> Seq Scan on public.prt2_l_p1_p2
+ Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
+ Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(70 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..79779d6
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,4118 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(47 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t2.a, t2.b
+ Sort Key: t1_3.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Sort Key: t1_4.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Sort Key: t1_5.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Sort Key: t1_3.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Sort Key: t1_4.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Sort Key: t1_5.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1_2.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(43 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(44 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+--
+-- negative testcases
+--
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/expected/rangefuncs.out b/src/test/regress/expected/rangefuncs.out
index f06cfa4..16e7f56 100644
--- a/src/test/regress/expected/rangefuncs.out
+++ b/src/test/regress/expected/rangefuncs.out
@@ -1,18 +1,19 @@
SELECT name, setting FROM pg_settings WHERE name LIKE 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
CREATE TABLE foo2(fooid int, f2 int);
INSERT INTO foo2 VALUES(1, 11);
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 8641769..b61ca3b 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -99,8 +99,9 @@ test: select_parallel
# ----------
# Another group of parallel tests
+# TODO: merge partition_join and multi_level_partition_join
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join multi_level_partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 835cf35..5b167b6 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -169,3 +169,5 @@ test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
+test: multi_level_partition_join
diff --git a/src/test/regress/sql/multi_level_partition_join.sql b/src/test/regress/sql/multi_level_partition_join.sql
new file mode 100644
index 0000000..31f0281
--- /dev/null
+++ b/src/test/regress/sql/multi_level_partition_join.sql
@@ -0,0 +1,95 @@
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((b + a));
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p1_p1;
+ANALYZE prt1_l_p1_p2;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES FROM (0) TO (100);
+CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((a + b));
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (1000) TO (1100);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (1100) TO (1200);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p1_p1;
+ANALYZE prt2_l_p1_p2;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
+ ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..9b2baeb
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,520 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- negative testcases
+--
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
multi_level_partition_join.patchapplication/x-download; name=multi_level_partition_join.patchDownload
diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c
index 98fed55..66537cf 100644
--- a/src/backend/catalog/partition.c
+++ b/src/backend/catalog/partition.c
@@ -2078,7 +2078,6 @@ find_partition_scheme(PlannerInfo *root, Relation relation)
int nparts;
int partnatts;
int cnt_pks;
- int cnt_parts;
PartitionScheme part_scheme = NULL;
/* No partition scheme for an unpartitioned relation. */
@@ -2088,21 +2087,6 @@ find_partition_scheme(PlannerInfo *root, Relation relation)
nparts = part_desc->nparts;
partnatts = part_key->partnatts;
- /*
- * For a multi-level partitioned table, we do not retain the partitioning
- * hierarchy while expanding RTE for the topmost parent. Thus the number of
- * children as per root->append_rel_list does not match the number of
- * partitions specified in the partition descriptor and hence the
- * partitioning scheme of a multi-partitioned table does not reflect the
- * true picture. So for now, treat a multi-partitioned table as not
- * partitioned.
- */
- for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
- {
- if (has_subclass(part_desc->oids[cnt_parts]))
- return NULL;
- }
-
/* Search for a matching partition scheme and return if found one. */
foreach (lc, root->part_schemes)
{
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 0a2c131..b8af23e 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -98,9 +98,6 @@ static void set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
static void generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *live_childrels, List *all_child_pathkeys,
bool partition_join_path);
-static Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
- RelOptInfo *rel,
- Relids required_outer);
static List *accumulate_append_subpath(List *subpaths, Path *path);
static void set_subquery_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
@@ -1646,7 +1643,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
*
* Returns NULL if unable to create such a path.
*/
-static Path *
+Path *
get_cheapest_parameterized_child_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer)
{
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 7839f0f..e7e06c8 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -1526,7 +1526,6 @@ add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
child_rel1->relids,
child_rel2->relids);
-
/*
* Construct restrictions applicable to the child join from
* those applicable to the parent join.
@@ -1619,6 +1618,58 @@ adjust_child_relids(Relids relids, List *append_rel_infos)
}
/*
+ * Replace any relid present in top_parent_relids with its child in
+ * child_relids. Members of child_relids can be multiple levels below top
+ * parent in the partition hierarchy.
+ */
+Relids
+adjust_child_relids_multilevel(PlannerInfo *root, Relids relids,
+ Relids child_relids, Relids top_parent_relids)
+{
+ List *appinfos;
+ Relids parent_relids = NULL;
+ ListCell *lc;
+ Relids result;
+ Relids tmp_result = NULL;
+
+ /*
+ * If the given relids set doesn't contain any of the top parent relids,
+ * it will remain unchanged.
+ */
+ if (!bms_overlap(relids, top_parent_relids))
+ return relids;
+
+ appinfos = find_appinfos_by_relids(root, child_relids);
+
+ /* Construct relids set for the immediate parent of the given child. */
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ parent_relids = bms_add_member(parent_relids, appinfo->parent_relid);
+ }
+
+ /* Recurse if immediate parent is not the top parent. */
+ if (!bms_equal(parent_relids, top_parent_relids))
+ {
+ tmp_result = adjust_child_relids_multilevel(root, relids,
+ parent_relids,
+ top_parent_relids);
+ relids = tmp_result;
+ }
+
+ result = adjust_child_relids(relids, appinfos);
+
+ /* Free memory consumed by any immediate result. */
+ if (tmp_result)
+ bms_free(tmp_result);
+
+ bms_free(parent_relids);
+ list_free(appinfos);
+ return result;
+}
+
+/*
* Returns true if there exists an equi-join condition for each pair of
* partition key from given relations being joined.
*/
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 3a223c8..baf0fdf 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -4097,13 +4097,32 @@ create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
* Search for a child path with pathkeys or parameterization
* matching that of the given path.
*/
- child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
- best_path->path.pathkeys,
- PATH_REQ_OUTER(&best_path->path),
- TOTAL_COST);
+ if (!PATH_REQ_OUTER(&best_path->path))
+ child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
+ best_path->path.pathkeys,
+ NULL,
+ TOTAL_COST);
+ else if (best_path->reparamterized_by)
+ {
+ child_path = get_cheapest_parameterized_child_path(root,
+ child_join,
+ best_path->old_param);
+
+ if (!child_path)
+ elog(ERROR, "Could not find a child-join path with required pathkeys or parameterization.");
+
+ child_path = reparameterize_path_by_child(root, child_path,
+ best_path->reparamterized_by);
+ }
+ else
+ child_path = get_cheapest_parameterized_child_path(root,
+ child_join,
+ PATH_REQ_OUTER(&best_path->path));
if (!child_path)
- elog(ERROR, "Could not find a path with required pathkeys.");
+ elog(ERROR, "Could not find a child-join path with required pathkeys or parameterization.");
+
+ MemoryContextSwitchTo(old_context);
MemoryContextSwitchTo(old_context);
@@ -4155,7 +4174,19 @@ create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
}
}
- child_plans = lappend(child_plans, child_plan);
+ /* Flatten Merge/Append plans. */
+ if (IsA(child_plan, Append))
+ {
+ Append *append = (Append *) child_plan;
+ child_plans = list_concat(child_plans, append->appendplans);
+ }
+ else if (IsA(child_plan, MergeAppend))
+ {
+ MergeAppend *mappend = (MergeAppend *) child_plan;
+ child_plans = list_concat(child_plans, mappend->mergeplans);
+ }
+ else
+ child_plans = lappend(child_plans, child_plan);
/*
* Reset the child_join memory context to reclaim the memory consumed
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index 84ce6b3..61f3886 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -14,6 +14,7 @@
*/
#include "postgres.h"
+#include "catalog/pg_class.h"
#include "catalog/pg_type.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/clauses.h"
@@ -623,8 +624,22 @@ create_lateral_join_info(PlannerInfo *root)
for (rti = 1; rti < root->simple_rel_array_size; rti++)
{
RelOptInfo *brel = root->simple_rel_array[rti];
+ RangeTblEntry *rte = root->simple_rte_array[rti];
- if (brel == NULL || brel->reloptkind != RELOPT_BASEREL)
+ if (brel == NULL)
+ continue;
+
+ /*
+ * If an "other rel" RTE is a "partitioned table", we must propagate
+ * the lateral info inherited all the way from the root parent to its
+ * children. That's because the children are not linked directly with
+ * the root parent via AppendRelInfo's unlike in case of a regular
+ * inheritance set (see expand_inherited_rtentry()). Failing to
+ * do this would result in those children not getting marked with the
+ * appropriate lateral info.
+ */
+ if (brel->reloptkind != RELOPT_BASEREL &&
+ rte->relkind != RELKIND_PARTITIONED_TABLE)
continue;
if (root->simple_rte_array[rti]->inh)
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 8b6a183..ecaffd0 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -110,6 +110,14 @@ static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
+static List *expand_inherited_rte_internal(PlannerInfo *root, RangeTblEntry *rte,
+ Index rti, PlanRowMark *oldrc,
+ LOCKMODE lockmode, bool flatten);
+static AppendRelInfo *process_one_child_table(PlannerInfo *root,
+ RangeTblEntry *parentRTE, Index parentRTindex,
+ Relation parentrel, Relation childrel,
+ PlanRowMark *parent_rc, bool inh,
+ RangeTblEntry **childRTE, Index *childRTindex);
/*
@@ -1323,7 +1331,10 @@ expand_inherited_tables(PlannerInfo *root)
/*
* expand_inherited_rtentry may add RTEs to parse->rtable; there is no
- * need to scan them since they can't have inh=true. So just scan as far
+ * need to scan them here since they can't normally have inh=true. If
+ * the inheritance set represents a partitioned table, some newly added
+ * RTEs will break the above rule if they are partitioned tables
+ * themselves, but they are expanded recursively. So just scan as far
* as the original end of the rtable list.
*/
nrtes = list_length(root->parse->rtable);
@@ -1346,9 +1357,11 @@ expand_inherited_tables(PlannerInfo *root)
* "inh" flag to prevent later code from looking for AppendRelInfos.
*
* Note that the original RTE is considered to represent the whole
- * inheritance set. The first of the generated RTEs is an RTE for the same
- * table, but with inh = false, to represent the parent table in its role
- * as a simple member of the inheritance set.
+ * inheritance set. If the RTE represents a partitioned table, inheritance
+ * set is expanded recursively. The first of the generated RTEs is an RTE
+ * for the same table, but with inh = false, to represent the parent table
+ * in its role as a simple member of the inheritance set. The same applies
+ * to each individual inheritance set in the recursive expansion case.
*
* A childless table is never considered to be an inheritance set; therefore
* a parent RTE must always have at least two associated AppendRelInfos.
@@ -1359,11 +1372,8 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
Query *parse = root->parse;
Oid parentOID;
PlanRowMark *oldrc;
- Relation oldrelation;
LOCKMODE lockmode;
- List *inhOIDs;
List *appinfos;
- ListCell *l;
/* Does RT entry allow inheritance? */
if (!rte->inh)
@@ -1404,19 +1414,69 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
else
lockmode = AccessShareLock;
- /* Scan for all members of inheritance set, acquire needed locks */
- inhOIDs = find_all_inheritors(parentOID, lockmode, NULL);
+ /*
+ * Do not flatten the inheritance hierarchy if partitioned table, unless
+ * this is the result relation.
+ */
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE &&
+ rti != root->parse->resultRelation)
+ appinfos = expand_inherited_rte_internal(root, rte, rti, oldrc,
+ lockmode, false);
+ else
+ appinfos = expand_inherited_rte_internal(root, rte, rti, oldrc,
+ lockmode, true);
+
+ /* Add to root->append_rel_list */
+ root->append_rel_list = list_concat(root->append_rel_list, appinfos);
+}
+
+/*
+ * expand_inherited_rte_internal
+ * Expand an inheritance set in either non-recursive (flatten=true) or
+ * recursive (flatten=false) manner.
+ *
+ * A inheritance hierarchy is not flttened if it represents a partitioned
+ * table. This allows later planning steps to apply any partitioning
+ * related optimizations in suitable manner.
+ */
+static List *
+expand_inherited_rte_internal(PlannerInfo *root, RangeTblEntry *rte,
+ Index rti, PlanRowMark *oldrc,
+ LOCKMODE lockmode, bool flatten)
+{
+ Oid parentOID;
+ Relation oldrelation;
+ List *inhOIDs;
+ List *appinfos = NIL;
+ ListCell *l;
+ bool has_descendents;
+
+ Assert(rte->rtekind == RTE_RELATION);
+ parentOID = rte->relid;
/*
- * Check that there's at least one descendant, else treat as no-child
+ * Get the list of inheritors.
+ *
+ * Also check that there's at least one descendant, else treat as no-child
* case. This could happen despite above has_subclass() check, if table
* once had a child but no longer does.
*/
- if (list_length(inhOIDs) < 2)
+ if (flatten)
+ {
+ inhOIDs = find_all_inheritors(parentOID, lockmode, NULL);
+ has_descendents = list_length(inhOIDs) >= 2;
+ }
+ else
+ {
+ inhOIDs = find_inheritance_children(parentOID, lockmode);
+ has_descendents = list_length(inhOIDs) >= 1;
+ }
+
+ if (!has_descendents)
{
/* Clear flag before returning */
rte->inh = false;
- return;
+ return NIL;
}
/*
@@ -1433,15 +1493,24 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
*/
oldrelation = heap_open(parentOID, NoLock);
+ /*
+ * Process parent relation in its role as inheritance set member; remember
+ * that parent table OID is not in inhOIDs if we did not flatten the
+ * inheritance tree.
+ */
+ if (!flatten)
+ appinfos = list_make1(process_one_child_table(root, rte, rti,
+ oldrelation, oldrelation,
+ oldrc, false,
+ NULL, NULL));
+
/* Scan the inheritance set and expand it */
- appinfos = NIL;
foreach(l, inhOIDs)
{
Oid childOID = lfirst_oid(l);
Relation newrelation;
RangeTblEntry *childrte;
Index childRTindex;
- AppendRelInfo *appinfo;
/* Open rel if needed; we already have required locks */
if (childOID != parentOID)
@@ -1462,75 +1531,29 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
}
/*
- * Build an RTE for the child, and attach to query's rangetable list.
- * We copy most fields of the parent's RTE, but replace relation OID
- * and relkind, and set inh = false. Also, set requiredPerms to zero
- * since all required permissions checks are done on the original RTE.
- */
- childrte = copyObject(rte);
- childrte->relid = childOID;
- childrte->relkind = newrelation->rd_rel->relkind;
- childrte->inh = false;
- childrte->requiredPerms = 0;
- parse->rtable = lappend(parse->rtable, childrte);
- childRTindex = list_length(parse->rtable);
-
- /*
- * Build an AppendRelInfo for this parent and child.
- */
- appinfo = makeNode(AppendRelInfo);
- appinfo->parent_relid = rti;
- appinfo->child_relid = childRTindex;
- appinfo->parent_reltype = oldrelation->rd_rel->reltype;
- appinfo->child_reltype = newrelation->rd_rel->reltype;
- make_inh_translation_list(oldrelation, newrelation, childRTindex,
- &appinfo->translated_vars);
- appinfo->parent_reloid = parentOID;
- appinfos = lappend(appinfos, appinfo);
-
- /*
- * Translate the column permissions bitmaps to the child's attnums (we
- * have to build the translated_vars list before we can do this). But
- * if this is the parent table, leave copyObject's result alone.
+ * process_one_child_table() performs the following actions for the
+ * child table:
*
- * Note: we need to do this even though the executor won't run any
- * permissions checks on the child RTE. The insertedCols/updatedCols
- * bitmaps may be examined for trigger-firing purposes.
- */
- if (childOID != parentOID)
- {
- childrte->selectedCols = translate_col_privs(rte->selectedCols,
- appinfo->translated_vars);
- childrte->insertedCols = translate_col_privs(rte->insertedCols,
- appinfo->translated_vars);
- childrte->updatedCols = translate_col_privs(rte->updatedCols,
- appinfo->translated_vars);
- }
-
- /*
- * Build a PlanRowMark if parent is marked FOR UPDATE/SHARE.
+ * 1. add a new RTE to the query rtable,
+ * 2. builds a PlanRowMark and adds to the root->rowMarks list
+ * 3. builds and returns AppendRelInfo for parent-child pair
*/
- if (oldrc)
+ appinfos = lappend(appinfos,
+ process_one_child_table(root, rte, rti,
+ oldrelation, newrelation,
+ oldrc, false,
+ &childrte, &childRTindex));
+
+ /* Recurse if we did not flatten the inheritance tree */
+ if (!flatten && has_subclass(childOID))
{
- PlanRowMark *newrc = makeNode(PlanRowMark);
-
- newrc->rti = childRTindex;
- newrc->prti = rti;
- newrc->rowmarkId = oldrc->rowmarkId;
- /* Reselect rowmark type, because relkind might not match parent */
- newrc->markType = select_rowmark_type(childrte, oldrc->strength);
- newrc->allMarkTypes = (1 << newrc->markType);
- newrc->strength = oldrc->strength;
- newrc->waitPolicy = oldrc->waitPolicy;
- newrc->isParent = false;
-
- /* Include child's rowmark type in parent's allMarkTypes */
- oldrc->allMarkTypes |= newrc->allMarkTypes;
-
- root->rowMarks = lappend(root->rowMarks, newrc);
+ Assert(childrte->relkind == RELKIND_PARTITIONED_TABLE);
+ childrte->inh = true;
+ appinfos = list_concat(appinfos,
+ expand_inherited_rte_internal(root, childrte,
+ childRTindex, oldrc, lockmode, flatten));
}
- /* Close child relations, but keep locks */
if (childOID != parentOID)
heap_close(newrelation, NoLock);
}
@@ -1546,11 +1569,108 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
{
/* Clear flag before returning */
rte->inh = false;
- return;
+ return NIL;
}
+ return appinfos;
+}
- /* Otherwise, OK to add to root->append_rel_list */
- root->append_rel_list = list_concat(root->append_rel_list, appinfos);
+/*
+ * process_one_child_table
+ * Process one child table in context of inheritance expansion for a
+ * query
+ *
+ * *childRTE & *childRTindex are output variables when non-NULL.
+ */
+static AppendRelInfo *
+process_one_child_table(PlannerInfo *root,
+ RangeTblEntry *parentRTE, Index parentRTindex,
+ Relation parentrel, Relation childrel,
+ PlanRowMark *parent_rc, bool inh,
+ RangeTblEntry **childRTE, Index *childRTindex)
+{
+ Query *parse = root->parse;
+ Oid parentOID = RelationGetRelid(parentrel),
+ childOID = RelationGetRelid(childrel);
+ RangeTblEntry *newrte;
+ Index newrti;
+ AppendRelInfo *appinfo;
+
+ /*
+ * Build an RTE for the child, and attach to query's rangetable list.
+ * We copy most fields of the parent's RTE, but replace relation OID
+ * and relkind, and set inh as requested. Also, set requiredPerms to
+ * zero since all required permissions checks are done on the original
+ * RTE.
+ */
+ newrte = copyObject(parentRTE);
+ newrte->relid = RelationGetRelid(childrel);
+ newrte->relkind = childrel->rd_rel->relkind;
+ newrte->inh = inh;
+ newrte->requiredPerms = 0;
+ parse->rtable = lappend(parse->rtable, newrte);
+ newrti = list_length(parse->rtable);
+
+ /* Return the child table RT entry and index if requested */
+ if (childRTE)
+ *childRTE = newrte;
+ if (childRTindex)
+ *childRTindex = newrti;
+
+ /*
+ * Build an AppendRelInfo for this parent and child.
+ */
+ appinfo = makeNode(AppendRelInfo);
+ appinfo->parent_relid = parentRTindex;
+ appinfo->child_relid = newrti;
+ appinfo->parent_reltype = parentrel->rd_rel->reltype;
+ appinfo->child_reltype = childrel->rd_rel->reltype;
+ make_inh_translation_list(parentrel, childrel, newrti,
+ &appinfo->translated_vars);
+ appinfo->parent_reloid = parentOID;
+
+ /*
+ * Translate the column permissions bitmaps to the child's attnums (we
+ * have to build the translated_vars list before we can do this). But
+ * if this is the parent table, leave copyObject's result alone.
+ *
+ * Note: we need to do this even though the executor won't run any
+ * permissions checks on the child RTE. The insertedCols/updatedCols
+ * bitmaps may be examined for trigger-firing purposes.
+ */
+ if (childOID != parentOID)
+ {
+ newrte->selectedCols = translate_col_privs(parentRTE->selectedCols,
+ appinfo->translated_vars);
+ newrte->insertedCols = translate_col_privs(parentRTE->insertedCols,
+ appinfo->translated_vars);
+ newrte->updatedCols = translate_col_privs(parentRTE->updatedCols,
+ appinfo->translated_vars);
+ }
+
+ /*
+ * Build a PlanRowMark if parent is marked FOR UPDATE/SHARE.
+ */
+ if (parent_rc)
+ {
+ PlanRowMark *newrc = makeNode(PlanRowMark);
+
+ newrc->rti = newrti;
+ newrc->prti = parentRTindex;
+ newrc->rowmarkId = parent_rc->rowmarkId;
+ /* Reselect rowmark type, because relkind might not match parent */
+ newrc->markType = select_rowmark_type(newrte, parent_rc->strength);
+ newrc->allMarkTypes = (1 << newrc->markType);
+ newrc->strength = parent_rc->strength;
+ newrc->waitPolicy = parent_rc->waitPolicy;
+ newrc->isParent = false;
+
+ /* Include child's rowmark type in parent's allMarkTypes */
+ parent_rc->allMarkTypes |= newrc->allMarkTypes;
+
+ root->rowMarks = lappend(root->rowMarks, newrc);
+ }
+
+ return appinfo;
}
/*
@@ -2166,23 +2286,47 @@ adjust_inherited_tlist(List *tlist, AppendRelInfo *context)
* adjust_appendrel_attrs_multilevel
* Apply Var translations from a toplevel appendrel parent down to a child.
*
- * In some cases we need to translate expressions referencing a baserel
+ * In some cases we need to translate expressions referencing a parent relation
* to reference an appendrel child that's multiple levels removed from it.
*/
Node *
adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel)
{
- AppendRelInfo *appinfo = find_childrel_appendrelinfo(root, child_rel);
- RelOptInfo *parent_rel = find_base_rel(root, appinfo->parent_relid);
+ List *appinfos = find_appinfos_by_relids(root, child_rel->relids);
+ RelOptInfo *parent_rel;
+
+ if (child_rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ {
+ AppendRelInfo *appinfo = linitial(appinfos);
+ parent_rel = find_base_rel(root, appinfo->parent_relid);
+ }
+ else
+ {
+ Relids parent_relids = NULL;
+ ListCell *lc;
+
+ /* Construct relids set for the immediate parent of the given child. */
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ parent_relids = bms_add_member(parent_relids, appinfo->parent_relid);
+ }
+
+ parent_rel = find_join_rel(root, parent_relids);
+ bms_free(parent_relids);
+ }
/* If parent is also a child, first recurse to apply its translations */
- if (parent_rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ if (IS_OTHER_REL(parent_rel))
node = adjust_appendrel_attrs_multilevel(root, node, parent_rel);
else
- Assert(parent_rel->reloptkind == RELOPT_BASEREL);
+ Assert(parent_rel->reloptkind == RELOPT_BASEREL ||
+ parent_rel->reloptkind == RELOPT_JOINREL);
+
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, list_make1(appinfo));
+ return adjust_appendrel_attrs(root, node, appinfos);
}
/*
@@ -2210,7 +2354,6 @@ build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
child_required_relids = adjust_child_relids(rinfo->required_relids,
append_rel_infos);
-
/* Nothing to do, if the clause does not need any translation. */
if (bms_equal(child_required_relids, rinfo->required_relids))
{
@@ -2279,3 +2422,50 @@ build_child_clauses(PlannerInfo *root, List *clauses, List *append_rel_infos)
return child_clauses;
}
+
+/*
+ * build_child_clauses_multilevel
+ * Similar to build_child_clauses but used when the child relation
+ * represented by child_relids is
+ * deeper down in the partition hierarchy reprepresented by parent
+ * relation with relids top_parent_relids.
+ */
+List *
+build_child_clauses_multilevel(PlannerInfo *root, List *clauses,
+ Relids child_relids, Relids top_parent_relids)
+{
+ List *appinfos;
+ Relids parent_relids = NULL;
+ ListCell *lc;
+ List *result;
+ List *tmp_result = NIL;
+
+ appinfos = find_appinfos_by_relids(root, child_relids);
+
+ /* Construct relids set for the immediate parent of the given child. */
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ parent_relids = bms_add_member(parent_relids, appinfo->parent_relid);
+ }
+
+ /* Recurse if immediate parent is not the top parent. */
+ if (!bms_equal(parent_relids, top_parent_relids))
+ {
+ clauses = build_child_clauses_multilevel(root, clauses, parent_relids,
+ top_parent_relids);
+ tmp_result = clauses;
+ }
+
+ result = build_child_clauses(root, clauses, appinfos);
+
+ /* Free memory consumed by any itermediate list. */
+ if (tmp_result)
+ list_free(tmp_result);
+
+ bms_free(parent_relids);
+ list_free(appinfos);
+
+ return result;
+}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index f5010e4..2fa0023 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -3403,7 +3403,6 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
Path *new_path;
ParamPathInfo *new_ppi;
ParamPathInfo *old_ppi;
- List *child_aris;
Relids required_outer;
/*
@@ -3446,6 +3445,11 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
memcpy(new_path, path, sizeof(AppendPath));
break;
+ case T_PartitionJoinPath:
+ new_path = (Path *) makeNode(PartitionJoinPath);
+ memcpy(new_path, path, sizeof(PartitionJoinPath));
+ break;
+
/*
* TODO:
* If this method of translation is fine add more path types here.
@@ -3456,16 +3460,12 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
return NULL;
}
- /*
- * Gather AppendRelInfos of the base partition relations in the outer child
- * relation. We need those for translating parent path to that of child by
- * substituting parent Var nodes and relids with those of children.
- */
- child_aris = find_appinfos_by_relids(root, child_rel->relids);
-
/* Adjust the parameterization information. */
old_ppi = new_path->param_info;
- required_outer = adjust_child_relids(old_ppi->ppi_req_outer, child_aris);
+ required_outer = adjust_child_relids_multilevel(root,
+ old_ppi->ppi_req_outer,
+ child_rel->relids,
+ child_rel->top_parent_relids);
/* If we already have a PPI for this parameterization, just return it */
new_ppi = find_param_path_info(new_path->parent, required_outer);
@@ -3476,8 +3476,10 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
new_ppi = makeNode(ParamPathInfo);
new_ppi->ppi_req_outer = required_outer;
new_ppi->ppi_rows = old_ppi->ppi_rows;
- new_ppi->ppi_clauses = build_child_clauses(root, old_ppi->ppi_clauses,
- child_aris);
+ new_ppi->ppi_clauses = build_child_clauses_multilevel(root,
+ old_ppi->ppi_clauses,
+ child_rel->relids,
+ child_rel->top_parent_relids);
new_path->parent->ppilist = lappend(new_path->parent->ppilist, new_ppi);
}
else
@@ -3493,6 +3495,7 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
if (bms_overlap(path->parent->lateral_relids, child_rel->top_parent_relids))
{
MemoryContext old_context;
+ List *exprs;
/*
* Allocate the target in planner's context, since they are copies as
@@ -3500,9 +3503,12 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
*/
old_context = MemoryContextSwitchTo(root->planner_cxt);
new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
- new_path->pathtarget->exprs = (List *) adjust_appendrel_attrs(root,
- (Node *) new_path->pathtarget->exprs,
- child_aris);
+ exprs = new_path->pathtarget->exprs;
+ exprs = (List *) adjust_appendrel_attrs_multilevel(root,
+ (Node *) exprs,
+ child_rel);
+ new_path->pathtarget->exprs = exprs;
+
MemoryContextSwitchTo(old_context);
}
@@ -3524,9 +3530,10 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
jpath->innerjoinpath = reparameterize_path_by_child(root,
jpath->innerjoinpath,
child_rel);
- jpath->joinrestrictinfo = build_child_clauses(root,
- jpath->joinrestrictinfo,
- child_aris);
+ jpath->joinrestrictinfo = build_child_clauses_multilevel(root,
+ jpath->joinrestrictinfo,
+ child_rel->relids,
+ child_rel->top_parent_relids);
}
break;
@@ -3543,16 +3550,38 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
child_rel));
apath->subpaths = subpaths;
}
+ break;
case T_IndexPath:
{
IndexPath *ipath = (IndexPath *)new_path;
- ipath->indexclauses = build_child_clauses(root, ipath->indexclauses,
- child_aris);
- ipath->indexquals = build_child_clauses(root, ipath->indexquals,
- child_aris);
+ ipath->indexclauses = build_child_clauses_multilevel(root,
+ ipath->indexclauses,
+ child_rel->relids,
+ child_rel->top_parent_relids);
+
+ ipath->indexquals = build_child_clauses_multilevel(root,
+ ipath->indexquals,
+ child_rel->relids,
+ child_rel->top_parent_relids);
}
+ break;
+
+ case T_PartitionJoinPath:
+ {
+ PartitionJoinPath *pjpath = (PartitionJoinPath *)new_path;
+
+ /*
+ * The paths for the child-joins covered by PartitionJoinPath will
+ * be created later. If this PartitionJoinPath was reparameterized
+ * by child of another relations, we will need that relation to
+ * reparamterize the child-join paths.
+ */
+ pjpath->old_param = PATH_REQ_OUTER(path);
+ pjpath->reparamterized_by = child_rel;
+ }
+ break;
default:
/* Nothing to do. */
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 88e66e4..83074e0 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -1335,8 +1335,13 @@ relation_excluded_by_constraints(PlannerInfo *root,
if (predicate_refuted_by(safe_restrictions, safe_restrictions))
return true;
- /* Only plain relations have constraints */
- if (rte->rtekind != RTE_RELATION || rte->inh)
+ /*
+ * Only plain relations have constraints. We represent a partitioned
+ * table append member as its own append relation and hence would have
+ * set rte->inh in that case.
+ */
+ if (rte->rtekind != RTE_RELATION ||
+ (rte->inh && rte->relkind != RELKIND_PARTITIONED_TABLE))
return false;
/*
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index df5b60f..6bac09d 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -1515,6 +1515,12 @@ typedef struct LimitPath
typedef struct PartitionJoinPath
{
Path path;
+
+ /* If this path is result of reparameterization by child. */
+ Relids old_param; /* Older parameterization. */
+ RelOptInfo *reparamterized_by; /* Child relation by which this paths was
+ * reparamterized.
+ */
} PartitionJoinPath;
/*
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 5d7bcd9..361c081 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -55,6 +55,8 @@ extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
extern void generate_gather_paths(PlannerInfo *root, RelOptInfo *rel);
extern void generate_partition_wise_join_paths(PlannerInfo *root,
RelOptInfo *rel);
+extern Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
+ RelOptInfo *rel, Relids required_outer);
#ifdef OPTIMIZER_DEBUG
extern void debug_print_rel(PlannerInfo *root, RelOptInfo *rel);
@@ -225,5 +227,8 @@ extern PathKey *make_canonical_pathkey(PlannerInfo *root,
int strategy, bool nulls_first);
extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
+extern Relids adjust_child_relids_multilevel(PlannerInfo *root, Relids relids,
+ Relids child_relids,
+ Relids top_parent_relids);
#endif /* PATHS_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index 2483303..51c9057 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -69,5 +69,7 @@ extern RestrictInfo *build_child_restrictinfo(PlannerInfo *root,
RestrictInfo *rinfo, List *append_rel_infos);
extern List *build_child_clauses(PlannerInfo *root, List *clauses,
List *append_rel_infos);
+extern List *build_child_clauses_multilevel(PlannerInfo *root, List *clauses,
+ Relids child_relids, Relids top_parent_relids);
#endif /* PREP_H */
diff --git a/src/test/regress/expected/inherit.out b/src/test/regress/expected/inherit.out
index 38ea8e8..3e6dd49 100644
--- a/src/test/regress/expected/inherit.out
+++ b/src/test/regress/expected/inherit.out
@@ -1645,15 +1645,15 @@ explain (costs off) select * from range_list_parted;
Append
-> Seq Scan on range_list_parted
-> Seq Scan on part_1_10
- -> Seq Scan on part_10_20
- -> Seq Scan on part_21_30
- -> Seq Scan on part_40_inf
-> Seq Scan on part_1_10_ab
-> Seq Scan on part_1_10_cd
+ -> Seq Scan on part_10_20
-> Seq Scan on part_10_20_ab
-> Seq Scan on part_10_20_cd
+ -> Seq Scan on part_21_30
-> Seq Scan on part_21_30_ab
-> Seq Scan on part_21_30_cd
+ -> Seq Scan on part_40_inf
-> Seq Scan on part_40_inf_ab
-> Seq Scan on part_40_inf_cd
-> Seq Scan on part_40_inf_null
@@ -1681,18 +1681,18 @@ explain (costs off) select * from range_list_parted where b = 'ab';
Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_1_10
Filter: (b = 'ab'::bpchar)
- -> Seq Scan on part_10_20
- Filter: (b = 'ab'::bpchar)
- -> Seq Scan on part_21_30
- Filter: (b = 'ab'::bpchar)
- -> Seq Scan on part_40_inf
- Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_1_10_ab
Filter: (b = 'ab'::bpchar)
+ -> Seq Scan on part_10_20
+ Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_10_20_ab
Filter: (b = 'ab'::bpchar)
+ -> Seq Scan on part_21_30
+ Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_21_30_ab
Filter: (b = 'ab'::bpchar)
+ -> Seq Scan on part_40_inf
+ Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_40_inf_ab
Filter: (b = 'ab'::bpchar)
(19 rows)
@@ -1705,14 +1705,14 @@ explain (costs off) select * from range_list_parted where a between 3 and 23 and
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_1_10
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
- -> Seq Scan on part_10_20
- Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
- -> Seq Scan on part_21_30
- Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_1_10_ab
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
+ -> Seq Scan on part_10_20
+ Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_10_20_ab
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
+ -> Seq Scan on part_21_30
+ Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_21_30_ab
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
(15 rows)
@@ -1752,24 +1752,24 @@ explain (costs off) select * from range_list_parted where a is not null and a <
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_1_10
Filter: ((a IS NOT NULL) AND (a < 67))
- -> Seq Scan on part_10_20
- Filter: ((a IS NOT NULL) AND (a < 67))
- -> Seq Scan on part_21_30
- Filter: ((a IS NOT NULL) AND (a < 67))
- -> Seq Scan on part_40_inf
- Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_1_10_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_1_10_cd
Filter: ((a IS NOT NULL) AND (a < 67))
+ -> Seq Scan on part_10_20
+ Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_10_20_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_10_20_cd
Filter: ((a IS NOT NULL) AND (a < 67))
+ -> Seq Scan on part_21_30
+ Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_21_30_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_21_30_cd
Filter: ((a IS NOT NULL) AND (a < 67))
+ -> Seq Scan on part_40_inf
+ Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_40_inf_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_40_inf_cd
diff --git a/src/test/regress/expected/multi_level_partition_join.out b/src/test/regress/expected/multi_level_partition_join.out
index d40ae55..97b1e79 100644
--- a/src/test/regress/expected/multi_level_partition_join.out
+++ b/src/test/regress/expected/multi_level_partition_join.out
@@ -1,21 +1,19 @@
+-- Encourage partition-wise join plans.
+SET partition_wise_plan_weight TO 0.1;
--
-- multi-leveled partitions
--
CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
-CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (b);
-CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES FROM (0) TO (100);
-CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250);
CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
-CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((b + a));
-CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (1000) TO (1100);
-CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (1100) TO (1200);
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (500) TO (550);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (550) TO (600);
INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
ANALYZE prt1_l;
ANALYZE prt1_l_p1;
-ANALYZE prt1_l_p1_p1;
-ANALYZE prt1_l_p1_p2;
ANALYZE prt1_l_p2;
ANALYZE prt1_l_p2_p1;
ANALYZE prt1_l_p2_p2;
@@ -26,20 +24,16 @@ ANALYZE prt1_l_p3_p2;
-- results are tested.
CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
-CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (a);
-CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES FROM (0) TO (100);
-CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250);
CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
-CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((a + b));
-CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (1000) TO (1100);
-CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (1100) TO (1200);
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (500) TO (525);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (525) TO (600);
INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
ANALYZE prt2_l;
ANALYZE prt2_l_p1;
-ANALYZE prt2_l_p1_p1;
-ANALYZE prt2_l_p1_p2;
ANALYZE prt2_l_p2;
ANALYZE prt2_l_p2_p1;
ANALYZE prt2_l_p2_p2;
@@ -49,77 +43,70 @@ ANALYZE prt2_l_p3_p2;
-- TODO: This table is created only for testing the results. Remove once
-- results are tested.
CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+-- inner join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
Sort
Output: t1.a, t1.c, t2.b, t2.c
Sort Key: t1.a
-> Append
-> Hash Join
Output: t1.a, t1.c, t2.b, t2.c
- Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
- -> Seq Scan on public.prt2_l_p1_p1 t2
- Output: t2.b, t2.c, t2.a
+ Hash Cond: ((t2.b = t1.a) AND ((t2.c)::text = (t1.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t2
+ Output: t2.b, t2.c
-> Hash
- Output: t1.a, t1.c, t1.b
- -> Seq Scan on public.prt1_l_p1_p1 t1
- Output: t1.a, t1.c, t1.b
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.c
Filter: ((t1.a % 25) = 0)
-> Hash Join
Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
- Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
- -> Seq Scan on public.prt2_l_p1_p2 t2_1
- Output: t2_1.b, t2_1.c, t2_1.a
+ Hash Cond: ((t2_1.b = t1_1.a) AND ((t2_1.c)::text = (t1_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_1
+ Output: t2_1.b, t2_1.c
-> Hash
- Output: t1_1.a, t1_1.c, t1_1.b
- -> Seq Scan on public.prt1_l_p1_p2 t1_1
- Output: t1_1.a, t1_1.c, t1_1.b
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.c
Filter: ((t1_1.a % 25) = 0)
-> Hash Join
Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
- Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
- -> Seq Scan on public.prt2_l_p2_p1 t2_2
- Output: t2_2.b, t2_2.c, t2_2.a
+ Hash Cond: ((t2_2.b = t1_2.a) AND ((t2_2.c)::text = (t1_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_2
+ Output: t2_2.b, t2_2.c
-> Hash
- Output: t1_2.a, t1_2.c, t1_2.b
- -> Seq Scan on public.prt1_l_p2_p1 t1_2
- Output: t1_2.a, t1_2.c, t1_2.b
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.c
Filter: ((t1_2.a % 25) = 0)
-> Hash Join
Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
- Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
- -> Seq Scan on public.prt2_l_p2_p2 t2_3
- Output: t2_3.b, t2_3.c, t2_3.a
+ Hash Cond: ((t2_3.b = t1_3.a) AND ((t2_3.c)::text = (t1_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c
-> Hash
- Output: t1_3.a, t1_3.c, t1_3.b
- -> Seq Scan on public.prt1_l_p2_p2 t1_3
- Output: t1_3.a, t1_3.c, t1_3.b
- Filter: ((t1_3.a % 25) = 0)
- -> Hash Join
- Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
- Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
- -> Seq Scan on public.prt2_l_p3_p1 t2_4
- Output: t2_4.b, t2_4.c, t2_4.a
- -> Hash
- Output: t1_4.a, t1_4.c, t1_4.b
- -> Seq Scan on public.prt1_l_p3_p1 t1_4
- Output: t1_4.a, t1_4.c, t1_4.b
- Filter: ((t1_4.a % 25) = 0)
- -> Hash Join
- Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
- Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
- -> Seq Scan on public.prt2_l_p3_p2 t2_5
- Output: t2_5.b, t2_5.c, t2_5.a
- -> Hash
- Output: t1_5.a, t1_5.c, t1_5.b
- -> Seq Scan on public.prt1_l_p3_p2 t1_5
- Output: t1_5.a, t1_5.c, t1_5.b
- Filter: ((t1_5.a % 25) = 0)
-(64 rows)
+ Output: t1_3.a, t1_3.c
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+(56 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -128,7 +115,7 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1
450 | 0450 | 450 | 0450
(4 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -137,77 +124,70 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND
450 | 0450 | 450 | 0450
(4 rows)
+-- left join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
Sort
Output: t1.a, t1.c, t2.b, t2.c
Sort Key: t1.a, t2.b
-> Append
-> Hash Right Join
Output: t1.a, t1.c, t2.b, t2.c
- Hash Cond: ((t2.b = t1.a) AND (t2.a = t1.b) AND ((t2.c)::text = (t1.c)::text) AND ((t2.a + t2.b) = (t1.b + t1.a)))
- -> Seq Scan on public.prt2_l_p1_p1 t2
- Output: t2.b, t2.c, t2.a
+ Hash Cond: ((t2.b = t1.a) AND ((t2.c)::text = (t1.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t2
+ Output: t2.b, t2.c
-> Hash
- Output: t1.a, t1.c, t1.b
- -> Seq Scan on public.prt1_l_p1_p1 t1
- Output: t1.a, t1.c, t1.b
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.c
Filter: ((t1.a % 25) = 0)
-> Hash Right Join
Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
- Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.a = t1_1.b) AND ((t2_1.c)::text = (t1_1.c)::text) AND ((t2_1.a + t2_1.b) = (t1_1.b + t1_1.a)))
- -> Seq Scan on public.prt2_l_p1_p2 t2_1
- Output: t2_1.b, t2_1.c, t2_1.a
+ Hash Cond: ((t2_1.b = t1_1.a) AND ((t2_1.c)::text = (t1_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_1
+ Output: t2_1.b, t2_1.c
-> Hash
- Output: t1_1.a, t1_1.c, t1_1.b
- -> Seq Scan on public.prt1_l_p1_p2 t1_1
- Output: t1_1.a, t1_1.c, t1_1.b
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.c
Filter: ((t1_1.a % 25) = 0)
-> Hash Right Join
Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
- Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.a = t1_2.b) AND ((t2_2.c)::text = (t1_2.c)::text) AND ((t2_2.a + t2_2.b) = (t1_2.b + t1_2.a)))
- -> Seq Scan on public.prt2_l_p2_p1 t2_2
- Output: t2_2.b, t2_2.c, t2_2.a
+ Hash Cond: ((t2_2.b = t1_2.a) AND ((t2_2.c)::text = (t1_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_2
+ Output: t2_2.b, t2_2.c
-> Hash
- Output: t1_2.a, t1_2.c, t1_2.b
- -> Seq Scan on public.prt1_l_p2_p1 t1_2
- Output: t1_2.a, t1_2.c, t1_2.b
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.c
Filter: ((t1_2.a % 25) = 0)
-> Hash Right Join
Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
- Hash Cond: ((t2_3.b = t1_3.a) AND (t2_3.a = t1_3.b) AND ((t2_3.c)::text = (t1_3.c)::text) AND ((t2_3.a + t2_3.b) = (t1_3.b + t1_3.a)))
- -> Seq Scan on public.prt2_l_p2_p2 t2_3
- Output: t2_3.b, t2_3.c, t2_3.a
- -> Hash
- Output: t1_3.a, t1_3.c, t1_3.b
- -> Seq Scan on public.prt1_l_p2_p2 t1_3
- Output: t1_3.a, t1_3.c, t1_3.b
- Filter: ((t1_3.a % 25) = 0)
- -> Hash Right Join
- Output: t1_4.a, t1_4.c, t2_4.b, t2_4.c
- Hash Cond: ((t2_4.b = t1_4.a) AND (t2_4.a = t1_4.b) AND ((t2_4.c)::text = (t1_4.c)::text) AND ((t2_4.a + t2_4.b) = (t1_4.b + t1_4.a)))
- -> Seq Scan on public.prt2_l_p3_p1 t2_4
- Output: t2_4.b, t2_4.c, t2_4.a
+ Hash Cond: ((t2_3.b = t1_3.a) AND ((t2_3.c)::text = (t1_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c
-> Hash
- Output: t1_4.a, t1_4.c, t1_4.b
- -> Seq Scan on public.prt1_l_p3_p1 t1_4
- Output: t1_4.a, t1_4.c, t1_4.b
- Filter: ((t1_4.a % 25) = 0)
- -> Hash Right Join
- Output: t1_5.a, t1_5.c, t2_5.b, t2_5.c
- Hash Cond: ((t2_5.b = t1_5.a) AND (t2_5.a = t1_5.b) AND ((t2_5.c)::text = (t1_5.c)::text) AND ((t2_5.a + t2_5.b) = (t1_5.b + t1_5.a)))
- -> Seq Scan on public.prt2_l_p3_p2 t2_5
- Output: t2_5.b, t2_5.c, t2_5.a
- -> Hash
- Output: t1_5.a, t1_5.c, t1_5.b
- -> Seq Scan on public.prt1_l_p3_p2 t1_5
- Output: t1_5.a, t1_5.c, t1_5.b
- Filter: ((t1_5.a % 25) = 0)
-(64 rows)
+ Output: t1_3.a, t1_3.c
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+(56 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -224,7 +204,7 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b
550 | 0550 | |
(12 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -241,10 +221,11 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.
550 | 0550 | |
(12 rows)
+-- right join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
Sort
Output: t1.a, t1.c, t2.b, t2.c
Sort Key: t1.a, t2.b
@@ -253,67 +234,59 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b
-> Append
-> Hash Right Join
Output: t2.b, t2.c, t1.a, t1.c
- Hash Cond: ((t1.a = t2.b) AND (t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text) AND ((t1.b + t1.a) = (t2.a + t2.b)))
- -> Seq Scan on public.prt1_l_p1_p1 t1
- Output: t1.a, t1.c, t1.b
+ Hash Cond: ((t1.a = t2.b) AND ((t1.c)::text = (t2.c)::text))
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.c
-> Hash
- Output: t2.b, t2.c, t2.a
- -> Seq Scan on public.prt2_l_p1_p1 t2
- Output: t2.b, t2.c, t2.a
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_l_p1 t2
+ Output: t2.b, t2.c
Filter: ((t2.b % 25) = 0)
-> Hash Right Join
Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
- Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.b = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text) AND ((t1_1.b + t1_1.a) = (t2_1.a + t2_1.b)))
- -> Seq Scan on public.prt1_l_p1_p2 t1_1
- Output: t1_1.a, t1_1.c, t1_1.b
+ Hash Cond: ((t1_1.a = t2_1.b) AND ((t1_1.c)::text = (t2_1.c)::text))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.c
-> Hash
- Output: t2_1.b, t2_1.c, t2_1.a
- -> Seq Scan on public.prt2_l_p1_p2 t2_1
- Output: t2_1.b, t2_1.c, t2_1.a
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_l_p2_p1 t2_1
+ Output: t2_1.b, t2_1.c
Filter: ((t2_1.b % 25) = 0)
-> Hash Right Join
Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
- Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.b = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text) AND ((t1_2.b + t1_2.a) = (t2_2.a + t2_2.b)))
- -> Seq Scan on public.prt1_l_p2_p1 t1_2
- Output: t1_2.a, t1_2.c, t1_2.b
+ Hash Cond: ((t1_2.a = t2_2.b) AND ((t1_2.c)::text = (t2_2.c)::text))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.c
-> Hash
- Output: t2_2.b, t2_2.c, t2_2.a
- -> Seq Scan on public.prt2_l_p2_p1 t2_2
- Output: t2_2.b, t2_2.c, t2_2.a
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_l_p2_p2 t2_2
+ Output: t2_2.b, t2_2.c
Filter: ((t2_2.b % 25) = 0)
-> Hash Right Join
Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
- Hash Cond: ((t1_3.a = t2_3.b) AND (t1_3.b = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text) AND ((t1_3.b + t1_3.a) = (t2_3.a + t2_3.b)))
- -> Seq Scan on public.prt1_l_p2_p2 t1_3
- Output: t1_3.a, t1_3.c, t1_3.b
- -> Hash
- Output: t2_3.b, t2_3.c, t2_3.a
- -> Seq Scan on public.prt2_l_p2_p2 t2_3
- Output: t2_3.b, t2_3.c, t2_3.a
- Filter: ((t2_3.b % 25) = 0)
- -> Hash Right Join
- Output: t2_4.b, t2_4.c, t1_4.a, t1_4.c
- Hash Cond: ((t1_4.a = t2_4.b) AND (t1_4.b = t2_4.a) AND ((t1_4.c)::text = (t2_4.c)::text) AND ((t1_4.b + t1_4.a) = (t2_4.a + t2_4.b)))
- -> Seq Scan on public.prt1_l_p3_p1 t1_4
- Output: t1_4.a, t1_4.c, t1_4.b
- -> Hash
- Output: t2_4.b, t2_4.c, t2_4.a
- -> Seq Scan on public.prt2_l_p3_p1 t2_4
- Output: t2_4.b, t2_4.c, t2_4.a
- Filter: ((t2_4.b % 25) = 0)
- -> Hash Right Join
- Output: t2_5.b, t2_5.c, t1_5.a, t1_5.c
- Hash Cond: ((t1_5.a = t2_5.b) AND (t1_5.b = t2_5.a) AND ((t1_5.c)::text = (t2_5.c)::text) AND ((t1_5.b + t1_5.a) = (t2_5.a + t2_5.b)))
- -> Seq Scan on public.prt1_l_p3_p2 t1_5
- Output: t1_5.a, t1_5.c, t1_5.b
+ Hash Cond: ((t1_3.a = t2_3.b) AND ((t1_3.c)::text = (t2_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.c
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c
-> Hash
- Output: t2_5.b, t2_5.c, t2_5.a
- -> Seq Scan on public.prt2_l_p3_p2 t2_5
- Output: t2_5.b, t2_5.c, t2_5.a
- Filter: ((t2_5.b % 25) = 0)
-(66 rows)
+ Output: t2_3.b, t2_3.c
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c
+ Filter: ((t2_4.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c
+ Filter: ((t2_5.b % 25) = 0)
+(58 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -326,7 +299,7 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b
| | 525 | 0525
(8 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -339,83 +312,76 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2
| | 525 | 0525
(8 rows)
+-- full join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
- QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
Sort
- Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
- Sort Key: prt1_l_p1_p1.a, prt2_l_p1_p1.b
+ Output: prt1_l_p1.a, prt1_l_p1.c, prt2_l_p1.b, prt2_l_p1.c
+ Sort Key: prt1_l_p1.a, prt2_l_p1.b
-> Append
-> Hash Full Join
- Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt2_l_p1_p1.b, prt2_l_p1_p1.c
- Hash Cond: ((prt1_l_p1_p1.a = prt2_l_p1_p1.b) AND (prt1_l_p1_p1.b = prt2_l_p1_p1.a) AND ((prt1_l_p1_p1.c)::text = (prt2_l_p1_p1.c)::text) AND ((prt1_l_p1_p1.b + prt1_l_p1_p1.a) = (prt2_l_p1_p1.a + prt2_l_p1_p1.b)))
- -> Seq Scan on public.prt1_l_p1_p1
- Output: prt1_l_p1_p1.a, prt1_l_p1_p1.c, prt1_l_p1_p1.b
- Filter: ((prt1_l_p1_p1.a % 25) = 0)
- -> Hash
- Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
- -> Seq Scan on public.prt2_l_p1_p1
- Output: prt2_l_p1_p1.b, prt2_l_p1_p1.c, prt2_l_p1_p1.a
- Filter: ((prt2_l_p1_p1.b % 25) = 0)
- -> Hash Full Join
- Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt2_l_p1_p2.b, prt2_l_p1_p2.c
- Hash Cond: ((prt1_l_p1_p2.a = prt2_l_p1_p2.b) AND (prt1_l_p1_p2.b = prt2_l_p1_p2.a) AND ((prt1_l_p1_p2.c)::text = (prt2_l_p1_p2.c)::text) AND ((prt1_l_p1_p2.b + prt1_l_p1_p2.a) = (prt2_l_p1_p2.a + prt2_l_p1_p2.b)))
- -> Seq Scan on public.prt1_l_p1_p2
- Output: prt1_l_p1_p2.a, prt1_l_p1_p2.c, prt1_l_p1_p2.b
- Filter: ((prt1_l_p1_p2.a % 25) = 0)
+ Output: prt1_l_p1.a, prt1_l_p1.c, prt2_l_p1.b, prt2_l_p1.c
+ Hash Cond: ((prt1_l_p1.a = prt2_l_p1.b) AND ((prt1_l_p1.c)::text = (prt2_l_p1.c)::text))
+ -> Seq Scan on public.prt1_l_p1
+ Output: prt1_l_p1.a, prt1_l_p1.c
+ Filter: ((prt1_l_p1.a % 25) = 0)
-> Hash
- Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
- -> Seq Scan on public.prt2_l_p1_p2
- Output: prt2_l_p1_p2.b, prt2_l_p1_p2.c, prt2_l_p1_p2.a
- Filter: ((prt2_l_p1_p2.b % 25) = 0)
+ Output: prt2_l_p1.b, prt2_l_p1.c
+ -> Seq Scan on public.prt2_l_p1
+ Output: prt2_l_p1.b, prt2_l_p1.c
+ Filter: ((prt2_l_p1.b % 25) = 0)
-> Hash Full Join
Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
- Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND (prt1_l_p2_p1.b = prt2_l_p2_p1.a) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text) AND ((prt1_l_p2_p1.b + prt1_l_p2_p1.a) = (prt2_l_p2_p1.a + prt2_l_p2_p1.b)))
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text))
-> Seq Scan on public.prt1_l_p2_p1
- Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt1_l_p2_p1.b
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c
Filter: ((prt1_l_p2_p1.a % 25) = 0)
-> Hash
- Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c
-> Seq Scan on public.prt2_l_p2_p1
- Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c, prt2_l_p2_p1.a
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c
Filter: ((prt2_l_p2_p1.b % 25) = 0)
-> Hash Full Join
Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
- Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND (prt1_l_p2_p2.b = prt2_l_p2_p2.a) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text) AND ((prt1_l_p2_p2.b + prt1_l_p2_p2.a) = (prt2_l_p2_p2.a + prt2_l_p2_p2.b)))
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text))
-> Seq Scan on public.prt1_l_p2_p2
- Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt1_l_p2_p2.b
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c
Filter: ((prt1_l_p2_p2.a % 25) = 0)
-> Hash
- Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c
-> Seq Scan on public.prt2_l_p2_p2
- Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c, prt2_l_p2_p2.a
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c
Filter: ((prt2_l_p2_p2.b % 25) = 0)
-> Hash Full Join
- Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt2_l_p3_p1.b, prt2_l_p3_p1.c
- Hash Cond: ((prt1_l_p3_p1.a = prt2_l_p3_p1.b) AND (prt1_l_p3_p1.b = prt2_l_p3_p1.a) AND ((prt1_l_p3_p1.c)::text = (prt2_l_p3_p1.c)::text) AND ((prt1_l_p3_p1.b + prt1_l_p3_p1.a) = (prt2_l_p3_p1.a + prt2_l_p3_p1.b)))
- -> Seq Scan on public.prt1_l_p3_p1
- Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c, prt1_l_p3_p1.b
- Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ Output: prt1_l_p3.a, prt1_l_p3.c, prt2_l_p3.b, prt2_l_p3.c
+ Hash Cond: ((prt1_l_p3.a = prt2_l_p3.b) AND ((prt1_l_p3.c)::text = (prt2_l_p3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt1_l_p3
+ Output: prt1_l_p3.a, prt1_l_p3.c
+ Filter: ((prt1_l_p3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
-> Hash
- Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
- -> Seq Scan on public.prt2_l_p3_p1
- Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c, prt2_l_p3_p1.a
- Filter: ((prt2_l_p3_p1.b % 25) = 0)
- -> Hash Full Join
- Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt2_l_p3_p2.b, prt2_l_p3_p2.c
- Hash Cond: ((prt1_l_p3_p2.a = prt2_l_p3_p2.b) AND (prt1_l_p3_p2.b = prt2_l_p3_p2.a) AND ((prt1_l_p3_p2.c)::text = (prt2_l_p3_p2.c)::text) AND ((prt1_l_p3_p2.b + prt1_l_p3_p2.a) = (prt2_l_p3_p2.a + prt2_l_p3_p2.b)))
- -> Seq Scan on public.prt1_l_p3_p2
- Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c, prt1_l_p3_p2.b
- Filter: ((prt1_l_p3_p2.a % 25) = 0)
- -> Hash
- Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
- -> Seq Scan on public.prt2_l_p3_p2
- Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c, prt2_l_p3_p2.a
- Filter: ((prt2_l_p3_p2.b % 25) = 0)
-(70 rows)
+ Output: prt2_l_p3.b, prt2_l_p3.c
+ -> Append
+ -> Seq Scan on public.prt2_l_p3
+ Output: prt2_l_p3.b, prt2_l_p3.c
+ Filter: ((prt2_l_p3.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(62 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -436,7 +402,7 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0
| | 525 | 0525
(16 rows)
-SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE uprt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l WHERE uprt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
a | c | b | c
-----+------+-----+------
0 | 0000 | 0 | 0000
@@ -456,3 +422,266 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0
| | 375 | 0375
| | 525 | 0525
(16 rows)
+
+-- lateral partition-wise join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t2.c, t2.b, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: ((t3.b = t2.a) AND ((t3.c)::text = (t2.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t2.a, t2.c, t2.b
+ -> Seq Scan on public.prt1_l_p1 t2
+ Output: t2.a, t2.c, t2.b
+ Filter: ((t1.a = t2.a) AND ((t1.c)::text = (t2.c)::text))
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.c, t2_1.b, t3_1.a, (LEAST(t1_1.a, t2_1.a, t3_1.a))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t2_1.c, t2_1.b, t3_1.a, LEAST(t1_1.a, t2_1.a, t3_1.a)
+ Hash Cond: ((t3_1.b = t2_1.a) AND ((t3_1.c)::text = (t2_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t2_1.a, t2_1.c, t2_1.b
+ -> Seq Scan on public.prt1_l_p2_p1 t2_1
+ Output: t2_1.a, t2_1.c, t2_1.b
+ Filter: ((t1_1.a = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text))
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.c, t2_2.b, t3_2.a, (LEAST(t1_2.a, t2_2.a, t3_2.a))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t2_2.c, t2_2.b, t3_2.a, LEAST(t1_2.a, t2_2.a, t3_2.a)
+ Hash Cond: ((t3_2.b = t2_2.a) AND ((t3_2.c)::text = (t2_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t2_2.a, t2_2.c, t2_2.b
+ -> Seq Scan on public.prt1_l_p2_p2 t2_2
+ Output: t2_2.a, t2_2.c, t2_2.b
+ Filter: ((t1_2.a = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text))
+ -> Nested Loop Left Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.c, t2_3.b, t3_3.a, (LEAST(t1_3.a, t2_3.a, t3_3.a))
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.b, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.b, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+ -> Hash Join
+ Output: t2_3.a, t2_3.c, t2_3.b, t3_3.a, LEAST(t1_3.a, t2_3.a, t3_3.a)
+ Hash Cond: ((t3_3.b = t2_3.a) AND ((t3_3.c)::text = (t2_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t3_3
+ Output: t3_3.a, t3_3.b, t3_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t3_4
+ Output: t3_4.a, t3_4.b, t3_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t3_5
+ Output: t3_5.a, t3_5.b, t3_5.c
+ -> Hash
+ Output: t2_3.a, t2_3.c, t2_3.b
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t2_3
+ Output: t2_3.a, t2_3.c, t2_3.b
+ Filter: ((t1_3.a = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p1 t2_4
+ Output: t2_4.a, t2_4.c, t2_4.b
+ Filter: ((t1_3.a = t2_4.a) AND ((t1_3.c)::text = (t2_4.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p2 t2_5
+ Output: t2_5.a, t2_5.c, t2_5.b
+ Filter: ((t1_3.a = t2_5.a) AND ((t1_3.c)::text = (t2_5.c)::text))
+(85 rows)
+
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
+-- lateral references with clauses without equi-join on partition key
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1_l t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p1 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p2 t1_4
+ Output: t1_4.a, t1_4.b, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3 t1_5
+ Output: t1_5.a, t1_5.b, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_6
+ Output: t1_6.a, t1_6.b, t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_7
+ Output: t1_7.a, t1_7.b, t1_7.c
+ Filter: ((t1_7.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t2.c, t2.b, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: ((t3.b = t2.a) AND ((t3.c)::text = (t2.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t2.a, t2.c, t2.b
+ -> Seq Scan on public.prt1_l_p1 t2
+ Output: t2.a, t2.c, t2.b
+ Filter: ((t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text))
+ -> Hash Join
+ Output: t2_1.a, t2_1.c, t2_1.b, t3_1.a, LEAST(t1.a, t2_1.a, t3_1.a)
+ Hash Cond: ((t3_1.b = t2_1.a) AND ((t3_1.c)::text = (t2_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t2_1.a, t2_1.c, t2_1.b
+ -> Seq Scan on public.prt1_l_p2_p1 t2_1
+ Output: t2_1.a, t2_1.c, t2_1.b
+ Filter: ((t1.b = t2_1.a) AND ((t1.c)::text = (t2_1.c)::text))
+ -> Hash Join
+ Output: t2_2.a, t2_2.c, t2_2.b, t3_2.a, LEAST(t1.a, t2_2.a, t3_2.a)
+ Hash Cond: ((t3_2.b = t2_2.a) AND ((t3_2.c)::text = (t2_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t2_2.a, t2_2.c, t2_2.b
+ -> Seq Scan on public.prt1_l_p2_p2 t2_2
+ Output: t2_2.a, t2_2.c, t2_2.b
+ Filter: ((t1.b = t2_2.a) AND ((t1.c)::text = (t2_2.c)::text))
+ -> Hash Join
+ Output: t2_3.a, t2_3.c, t2_3.b, t3_3.a, LEAST(t1.a, t2_3.a, t3_3.a)
+ Hash Cond: ((t3_3.b = t2_3.a) AND ((t3_3.c)::text = (t2_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t3_3
+ Output: t3_3.a, t3_3.b, t3_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t3_4
+ Output: t3_4.a, t3_4.b, t3_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t3_5
+ Output: t3_5.a, t3_5.b, t3_5.c
+ -> Hash
+ Output: t2_3.a, t2_3.c, t2_3.b
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t2_3
+ Output: t2_3.a, t2_3.c, t2_3.b
+ Filter: ((t1.b = t2_3.a) AND ((t1.c)::text = (t2_3.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p1 t2_4
+ Output: t2_4.a, t2_4.c, t2_4.b
+ Filter: ((t1.b = t2_4.a) AND ((t1.c)::text = (t2_4.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p2 t2_5
+ Output: t2_5.a, t2_5.c, t2_5.b
+ Filter: ((t1.b = t2_5.a) AND ((t1.c)::text = (t2_5.c)::text))
+(83 rows)
+
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
diff --git a/src/test/regress/sql/multi_level_partition_join.sql b/src/test/regress/sql/multi_level_partition_join.sql
index 31f0281..821c095 100644
--- a/src/test/regress/sql/multi_level_partition_join.sql
+++ b/src/test/regress/sql/multi_level_partition_join.sql
@@ -1,21 +1,20 @@
+-- Encourage partition-wise join plans.
+SET partition_wise_plan_weight TO 0.1;
+
--
-- multi-leveled partitions
--
CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
-CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (b);
-CREATE TABLE prt1_l_p1_p1 PARTITION OF prt1_l_p1 FOR VALUES FROM (0) TO (100);
-CREATE TABLE prt1_l_p1_p2 PARTITION OF prt1_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250);
CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
-CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((b + a));
-CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (1000) TO (1100);
-CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (1100) TO (1200);
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (500) TO (550);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (550) TO (600);
INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
ANALYZE prt1_l;
ANALYZE prt1_l_p1;
-ANALYZE prt1_l_p1_p1;
-ANALYZE prt1_l_p1_p2;
ANALYZE prt1_l_p2;
ANALYZE prt1_l_p2_p1;
ANALYZE prt1_l_p2_p2;
@@ -27,20 +26,16 @@ ANALYZE prt1_l_p3_p2;
CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
-CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250) PARTITION BY RANGE (a);
-CREATE TABLE prt2_l_p1_p1 PARTITION OF prt2_l_p1 FOR VALUES FROM (0) TO (100);
-CREATE TABLE prt2_l_p1_p2 PARTITION OF prt2_l_p1 FOR VALUES FROM (100) TO (250);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250);
CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
-CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE ((a + b));
-CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (1000) TO (1100);
-CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (1100) TO (1200);
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (500) TO (525);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (525) TO (600);
INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
ANALYZE prt2_l;
ANALYZE prt2_l_p1;
-ANALYZE prt2_l_p1_p1;
-ANALYZE prt2_l_p1_p2;
ANALYZE prt2_l_p2;
ANALYZE prt2_l_p2_p1;
ANALYZE prt2_l_p2_p2;
@@ -51,45 +46,50 @@ ANALYZE prt2_l_p3_p2;
-- results are tested.
CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+-- inner join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+-- left join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+-- right join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+-- full join
EXPLAIN (VERBOSE, COSTS OFF)
-SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
-SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.b = t2.a AND t1.c = t2.c AND t1.b + t1.a = t2.a + t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE uprt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l WHERE uprt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
--- lateral reference
+-- lateral partition-wise join
EXPLAIN (VERBOSE, COSTS OFF)
SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
- (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
- ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
- (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
- ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
- (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
- ON t1.a = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+-- lateral references with clauses without equi-join on partition key
EXPLAIN (VERBOSE, COSTS OFF)
SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
- (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
- ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
- (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
- ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
- (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.b = t3.a AND t2.c = t3.c AND t2.b + t2.a = t3.a + t3.b)) ss
- ON t1.b = ss.t2a AND t1.b = ss.t2a AND t1.c = ss.t2c AND t1.b + t1.a = ss.t2a + ss.t2b WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
On Mon, Jan 2, 2017 at 7:32 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
PFA the patch (pg_dp_join_v6.patch) with some bugs fixed and rebased
on the latest code.
Maybe not surprisingly given how fast things are moving around here
these days, this needs a rebase.
Apart from that, my overall comment on this patch is that it's huge:
37 files changed, 7993 insertions(+), 287 deletions(-)
Now, more than half of that is regression test cases and their output,
which you will certainly be asked to pare down in any version of this
intended for commit. But even excluding those, it's still a fairly
patch:
30 files changed, 2783 insertions(+), 272 deletions(-)
I think the reason this is so large is because there's a fair amount
of refactoring work that has been done as a precondition of the actual
meat of the patch, and no attempt has been made to separate the
refactoring work from the main body of the patch. I think that's
something that needs to be done. If you look at the way Amit Langote
submitted the partitioning patches and the follow-up bug fixes, he had
a series of patches 0001-blah, 0002-quux, etc. generated using
format-patch. Each patch had its own commit message written by him
explaining the purpose of that patch, links to relevant discussion,
etc. If you can separate this into more digestible chunks it will be
easier to get committed.
Other questions/comments:
Why does find_partition_scheme need to copy the partition bound
information instead of just pointing to it? Amit went to some trouble
to make sure that this can't change under us while we hold a lock on
the relation, and we'd better hold a lock on the relation if we're
planning a query against it.
I think the PartitionScheme stuff should live in the optimizer rather
that src/backend/catalog/partition.c. Maybe plancat.c? Perhaps we
eventually need a new file in the optimizer just for partitioning
stuff, but I'm not sure about that yet.
The fact that set_append_rel_size needs to reopen the relation to
extract a few more bits of information is not desirable. You need to
fish this information through in some other way; for example, you
could have get_relation_info() stash the needed bits in the
RelOptInfo.
+ * For two partitioned tables with the same
partitioning scheme, it is
+ * assumed that the Oids of matching partitions from
both the tables
+ * are placed at the same position in the array of
partition oids in
Rather than saying that we assume this, you should say why it has to
be true. (If it doesn't have to be true, we shouldn't assume it.)
+ * join relations. Partition tables should have same
layout as the
+ * parent table and hence should not need any
translation. But rest of
The same attributes have to be present with the same types, but they
can be rearranged. This comment seems to imply the contrary.
FRACTION_PARTS_TO_PLAN seems like it should be a GUC.
+ /*
+ * Add this relation to the list of samples ordered by
the increasing
+ * number of rows at appropriate place.
+ */
+ foreach (lc, ordered_child_nos)
+ {
+ int child_no = lfirst_int(lc);
+ RelOptInfo *other_childrel = rel->part_rels[child_no];
+
+ /*
+ * Keep track of child with lowest number of
rows but higher than the
+ * that of the child being inserted. Insert
the child before a
+ * child with highest number of rows lesser than it.
+ */
+ if (child_rel->rows <= other_childrel->rows)
+ insert_after = lc;
+ else
+ break;
+ }
Can we use quicksort instead of a hand-coded insertion sort?
+ if (bms_num_members(outer_relids) > 1)
Seems like bms_get_singleton_member could be used.
+ * Partitioning scheme in join relation indicates a possibilty that the
Spelling.
There seems to be no reason for create_partition_plan to be separated
from create_plan_recurse. You can just add another case for the new
path type.
Why does create_partition_join_path need to be separate from
create_partition_join_path_with_pathkeys? Couldn't that be combined
into a single function with a pathkeys argument that might sometimes
be NIL? I assume most of the logic is common.
From a sort of theoretical standpoint, the biggest danger of this
patch seems to be that by deferring path creation until a later stage
than normal, we could miss some important processing.
subquery_planner() does a lot of stuff after
expand_inherited_tables(); if any of those things, especially the ones
that happen AFTER path generation, have an effect on the paths, then
this code needs to compensate for those changes somehow. It seems
like having the planning of unsampled children get deferred until
create_plan() time is awfully surprising; here we are creating the
plan and suddenly what used to be a straightforward path->plan
translation is running around doing major planning work. I can't
entirely justify it, but I somehow have a feeling that work ought to
be moved earlier. Not sure exactly where.
This is not really a full review, mostly because I can't easily figure
out the motivation for all of the changes the patch makes. It makes a
lot of changes in a lot of places, and it's not really very easy to
understand why those changes are necessary. My comments above about
splitting the patch into a series of patches that can potentially be
reviewed and applied independently, with the main patch being the last
in the series, are a suggestion as to how to tackle that. There might
be some work that needs to or could be done on the comments, too. For
example, the patch splits out add_paths_to_append_rel from
set_append_rel_pathlist, but the comments don't say anything helpful
like "we need to do X after Y, because Z". They just say that we do
it. To some extent I think the comments in the optimizer have that
problem generally, so it's not entirely the fault of this patch;
still, the lack of those explanations makes the code reorganization
harder to follow, and might confuse future patch authors, too.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Thu, Feb 2, 2017 at 2:41 AM, Robert Haas <robertmhaas@gmail.com> wrote:
On Mon, Jan 2, 2017 at 7:32 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:PFA the patch (pg_dp_join_v6.patch) with some bugs fixed and rebased
on the latest code.Maybe not surprisingly given how fast things are moving around here
these days, this needs a rebase.Apart from that, my overall comment on this patch is that it's huge:
37 files changed, 7993 insertions(+), 287 deletions(-)
Now, more than half of that is regression test cases and their output,
which you will certainly be asked to pare down in any version of this
intended for commit.
Yes. I will work on that once the design and implementation is in
acceptable state. I have already toned down testcases compared to the
previous patch.
But even excluding those, it's still a fairly
patch:30 files changed, 2783 insertions(+), 272 deletions(-)
I think the reason this is so large is because there's a fair amount
of refactoring work that has been done as a precondition of the actual
meat of the patch, and no attempt has been made to separate the
refactoring work from the main body of the patch. I think that's
something that needs to be done. If you look at the way Amit Langote
submitted the partitioning patches and the follow-up bug fixes, he had
a series of patches 0001-blah, 0002-quux, etc. generated using
format-patch. Each patch had its own commit message written by him
explaining the purpose of that patch, links to relevant discussion,
etc. If you can separate this into more digestible chunks it will be
easier to get committed.
I will try to break down the patch into smaller, easy-to-review,
logically cohesive patches.
Other questions/comments:
Why does find_partition_scheme need to copy the partition bound
information instead of just pointing to it? Amit went to some trouble
to make sure that this can't change under us while we hold a lock on
the relation, and we'd better hold a lock on the relation if we're
planning a query against it.
PartitionScheme is shared across multiple relations, join or base,
partitioned similarly. Obviously it can't and does not need to point
partition bound informations (which should all be same) of all those
base relations. O the the face of it, it looks weird that it points to
only one of them, mostly the one which it encounters first. But, since
it's going to be the same partition bound information, it doesn't
matter which one. So, I think, we can point of any one of those. Do
you agree?
I think the PartitionScheme stuff should live in the optimizer rather
that src/backend/catalog/partition.c. Maybe plancat.c? Perhaps we
eventually need a new file in the optimizer just for partitioning
stuff, but I'm not sure about that yet.
I placed PartitionScheme stuff in partition.c because most of the
functions and structures in partition.c are not visible outside that
file. But I will try again to locate PartitionScheme to optimizer.
The fact that set_append_rel_size needs to reopen the relation to
extract a few more bits of information is not desirable. You need to
fish this information through in some other way; for example, you
could have get_relation_info() stash the needed bits in the
RelOptInfo.
I considered this option and discarded it, since not all partitioned
relations will have OIDs for partitions e.g. partitioned joins will
not have OIDs for their partitions. But now that I think of it, we
should probably store those OIDs just for the base relation and leave
them unused for non-base relations just like other base relation
specific fields in RelOptInfo.
+ * For two partitioned tables with the same partitioning scheme, it is + * assumed that the Oids of matching partitions from both the tables + * are placed at the same position in the array of partition oids inRather than saying that we assume this, you should say why it has to
be true. (If it doesn't have to be true, we shouldn't assume it.)
Will take care of this.
+ * join relations. Partition tables should have same layout as the + * parent table and hence should not need any translation. But rest ofThe same attributes have to be present with the same types, but they
can be rearranged. This comment seems to imply the contrary.
Hmm, will take care of this.
FRACTION_PARTS_TO_PLAN seems like it should be a GUC.
+1. Will take care of this. Does "representative_partitions_fraction"
or "sample_partition_fraction" look like a good GUC name? Any other
suggestions?
+ /* + * Add this relation to the list of samples ordered by the increasing + * number of rows at appropriate place. + */ + foreach (lc, ordered_child_nos) + { + int child_no = lfirst_int(lc); + RelOptInfo *other_childrel = rel->part_rels[child_no]; + + /* + * Keep track of child with lowest number of rows but higher than the + * that of the child being inserted. Insert the child before a + * child with highest number of rows lesser than it. + */ + if (child_rel->rows <= other_childrel->rows) + insert_after = lc; + else + break; + }Can we use quicksort instead of a hand-coded insertion sort?
I guess so, if I write comparison functions, which shouldn't be a
problem. Will try that.
+ if (bms_num_members(outer_relids) > 1)
Seems like bms_get_singleton_member could be used.
+ * Partitioning scheme in join relation indicates a possibilty that the
Spelling.
There seems to be no reason for create_partition_plan to be separated
from create_plan_recurse. You can just add another case for the new
path type.Why does create_partition_join_path need to be separate from
create_partition_join_path_with_pathkeys? Couldn't that be combined
into a single function with a pathkeys argument that might sometimes
be NIL? I assume most of the logic is common.From a sort of theoretical standpoint, the biggest danger of this
patch seems to be that by deferring path creation until a later stage
than normal, we could miss some important processing.
subquery_planner() does a lot of stuff after
expand_inherited_tables(); if any of those things, especially the ones
that happen AFTER path generation, have an effect on the paths, then
this code needs to compensate for those changes somehow. It seems
like having the planning of unsampled children get deferred until
create_plan() time is awfully surprising; here we are creating the
plan and suddenly what used to be a straightforward path->plan
translation is running around doing major planning work. I can't
entirely justify it, but I somehow have a feeling that work ought to
be moved earlier. Not sure exactly where.This is not really a full review, mostly because I can't easily figure
out the motivation for all of the changes the patch makes. It makes a
lot of changes in a lot of places, and it's not really very easy to
understand why those changes are necessary. My comments above about
splitting the patch into a series of patches that can potentially be
reviewed and applied independently, with the main patch being the last
in the series, are a suggestion as to how to tackle that. There might
be some work that needs to or could be done on the comments, too. For
example, the patch splits out add_paths_to_append_rel from
set_append_rel_pathlist, but the comments don't say anything helpful
like "we need to do X after Y, because Z". They just say that we do
it. To some extent I think the comments in the optimizer have that
problem generally, so it's not entirely the fault of this patch;
still, the lack of those explanations makes the code reorganization
harder to follow, and might confuse future patch authors, too.--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
sent the previous mail before completing my reply. Sorry for that.
Here's the rest of the reply.
+ if (bms_num_members(outer_relids) > 1)
Seems like bms_get_singleton_member could be used.
+ * Partitioning scheme in join relation indicates a possibilty that the
Spelling.
Will take care of this.
There seems to be no reason for create_partition_plan to be separated
from create_plan_recurse. You can just add another case for the new
path type.
Will take care of this.
Why does create_partition_join_path need to be separate from
create_partition_join_path_with_pathkeys? Couldn't that be combined
into a single function with a pathkeys argument that might sometimes
be NIL? I assume most of the logic is common.
Agreed. will take care of this.
From a sort of theoretical standpoint, the biggest danger of this
patch seems to be that by deferring path creation until a later stage
than normal, we could miss some important processing.
subquery_planner() does a lot of stuff after
expand_inherited_tables(); if any of those things, especially the ones
that happen AFTER path generation, have an effect on the paths, then
this code needs to compensate for those changes somehow. It seems
like having the planning of unsampled children get deferred until
create_plan() time is awfully surprising; here we are creating the
plan and suddenly what used to be a straightforward path->plan
translation is running around doing major planning work. I can't
entirely justify it, but I somehow have a feeling that work ought to
be moved earlier. Not sure exactly where.
I agree with this. Probably we should add a path tree mutator before
SS_identify_outer_params() to replace any Partition*Paths with
Merge/Append paths. The mutator will create paths for child-joins
within temporary memory context, copy the relevant paths and create
Merge/Append paths. There are two problems there 1. We have to write
code to copy paths; most of the paths would be flat copy but custom
scan paths might have some unexpected problems. 2. There will be many
surviving PartitionPaths, and all the corresponding child paths would
need copying and consume memory. In order to reduce that consumption,
we have run this mutator after set_cheapest() in subquery_planner();
but then nothing interesting happens between that and create_plan().
Expanding PartitionPaths during create_plan() does not need any path
copying and we expand only the PartitionPaths which will be converted
to plans. That does save a lot of memory; the reason why we defer
creating paths for child-joins.
This is not really a full review, mostly because I can't easily figure
out the motivation for all of the changes the patch makes. It makes a
lot of changes in a lot of places, and it's not really very easy to
understand why those changes are necessary. My comments above about
splitting the patch into a series of patches that can potentially be
reviewed and applied independently, with the main patch being the last
in the series, are a suggestion as to how to tackle that. There might
be some work that needs to or could be done on the comments, too. For
example, the patch splits out add_paths_to_append_rel from
set_append_rel_pathlist, but the comments don't say anything helpful
like "we need to do X after Y, because Z". They just say that we do
it. To some extent I think the comments in the optimizer have that
problem generally, so it's not entirely the fault of this patch;
still, the lack of those explanations makes the code reorganization
harder to follow, and might confuse future patch authors, too.
Specifically about add_paths_to_append_rel(), what do you expect the
comment to say? It would be obvious why we split that functionality
into a separate function: in fact, we don't necessarily explain why
certain code resides in a separate function in the comments. I think,
that particular comment (or for that matter other such comments in the
optimizer) can be removed altogether, since it just writes the
function names as an "English" sentence. I sometimes find those
comments useful, because I can read just those comments and forget
about the code, making comprehension easy. If highlighting is ON, your
brain habitually ignores the non-comment portions when required. I am
open to suggestions.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Per your suggestion I have split the patch into many smaller patches.
0001-Refactor-set_append_rel_pathlist.patch
0002-Refactor-make_join_rel.patch
0003-Refactor-adjust_appendrel_attrs.patch
0004-Refactor-build_join_rel.patch
0005-Add-function-find_param_path_info.patch
These four refactor existing code.
0006-Canonical-partition-scheme.patch
0007-Partition-wise-join-tests.patch -- just tests, they fail
0008-Partition-wise-join.patch -- actual patch implementing
partition-wise join, still some tests fail\
0009-Adjust-join-related-to-code-to-accept-child-relation.patch
0010-Parameterized-path-fixes.patch
0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patch
The last three patches change existing code to expect child(-join)
relations where they were not expected earlier.
Each patch has summary of the changes.
Partition-wise join for multi-level partitioned tables is not covered
by these patches. I will post those patches soon.
Other questions/comments:
Why does find_partition_scheme need to copy the partition bound
information instead of just pointing to it? Amit went to some trouble
to make sure that this can't change under us while we hold a lock on
the relation, and we'd better hold a lock on the relation if we're
planning a query against it.PartitionScheme is shared across multiple relations, join or base,
partitioned similarly. Obviously it can't and does not need to point
partition bound informations (which should all be same) of all those
base relations. O the the face of it, it looks weird that it points to
only one of them, mostly the one which it encounters first. But, since
it's going to be the same partition bound information, it doesn't
matter which one. So, I think, we can point of any one of those. Do
you agree?
Instead of copying PartitionBoundInfo, used pointer of the first
encountered one.
I think the PartitionScheme stuff should live in the optimizer rather
that src/backend/catalog/partition.c. Maybe plancat.c? Perhaps we
eventually need a new file in the optimizer just for partitioning
stuff, but I'm not sure about that yet.I placed PartitionScheme stuff in partition.c because most of the
functions and structures in partition.c are not visible outside that
file. But I will try again to locate PartitionScheme to optimizer.
Moved the code as per your suggestion.
The fact that set_append_rel_size needs to reopen the relation to
extract a few more bits of information is not desirable. You need to
fish this information through in some other way; for example, you
could have get_relation_info() stash the needed bits in the
RelOptInfo.I considered this option and discarded it, since not all partitioned
relations will have OIDs for partitions e.g. partitioned joins will
not have OIDs for their partitions. But now that I think of it, we
should probably store those OIDs just for the base relation and leave
them unused for non-base relations just like other base relation
specific fields in RelOptInfo.
Changed as per your suggestions.
+ * For two partitioned tables with the same partitioning scheme, it is + * assumed that the Oids of matching partitions from both the tables + * are placed at the same position in the array of partition oids inRather than saying that we assume this, you should say why it has to
be true. (If it doesn't have to be true, we shouldn't assume it.)Will take care of this.
Done. Please check.
+ * join relations. Partition tables should have same layout as the + * parent table and hence should not need any translation. But rest ofThe same attributes have to be present with the same types, but they
can be rearranged. This comment seems to imply the contrary.Hmm, will take care of this.
Done.
FRACTION_PARTS_TO_PLAN seems like it should be a GUC.
+1. Will take care of this. Does "representative_partitions_fraction"
or "sample_partition_fraction" look like a good GUC name? Any other
suggestions?
used "sample_partition_fraction" for now. Suggestions are welcome.
+ /* + * Add this relation to the list of samples ordered by the increasing + * number of rows at appropriate place. + */ + foreach (lc, ordered_child_nos) + { + int child_no = lfirst_int(lc); + RelOptInfo *other_childrel = rel->part_rels[child_no]; + + /* + * Keep track of child with lowest number of rows but higher than the + * that of the child being inserted. Insert the child before a + * child with highest number of rows lesser than it. + */ + if (child_rel->rows <= other_childrel->rows) + insert_after = lc; + else + break; + }Can we use quicksort instead of a hand-coded insertion sort?
I guess so, if I write comparison functions, which shouldn't be a
problem. Will try that.
Done.
+ if (bms_num_members(outer_relids) > 1)
Seems like bms_get_singleton_member could be used.
That code is not required any more.
+ * Partitioning scheme in join relation indicates a possibilty that the
Spelling.
Done.
There seems to be no reason for create_partition_plan to be separated
from create_plan_recurse. You can just add another case for the new
path type.
Done.
Why does create_partition_join_path need to be separate from
create_partition_join_path_with_pathkeys? Couldn't that be combined
into a single function with a pathkeys argument that might sometimes
be NIL? I assume most of the logic is common.
Combined those into a single function.
From a sort of theoretical standpoint, the biggest danger of this
patch seems to be that by deferring path creation until a later stage
than normal, we could miss some important processing.
subquery_planner() does a lot of stuff after
expand_inherited_tables(); if any of those things, especially the ones
that happen AFTER path generation, have an effect on the paths, then
this code needs to compensate for those changes somehow. It seems
like having the planning of unsampled children get deferred until
create_plan() time is awfully surprising; here we are creating the
plan and suddenly what used to be a straightforward path->plan
translation is running around doing major planning work. I can't
entirely justify it, but I somehow have a feeling that work ought to
be moved earlier. Not sure exactly where.
Pasting my previous replies here to keep everything in one mail.
I agree with this. Probably we should add a path tree mutator before
SS_identify_outer_params() to replace any Partition*Paths with
Merge/Append paths. The mutator will create paths for child-joins
within temporary memory context, copy the relevant paths and create
Merge/Append paths. There are two problems there 1. We have to write
code to copy paths; most of the paths would be flat copy but custom
scan paths might have some unexpected problems. 2. There will be many
surviving PartitionPaths, and all the corresponding child paths would
need copying and consume memory. In order to reduce that consumption,
we have run this mutator after set_cheapest() in subquery_planner();
but then nothing interesting happens between that and create_plan().
Expanding PartitionPaths during create_plan() does not need any path
copying and we expand only the PartitionPaths which will be converted
to plans. That does save a lot of memory; the reason why we defer
creating paths for child-joins.
This is not really a full review, mostly because I can't easily figure
out the motivation for all of the changes the patch makes. It makes a
lot of changes in a lot of places, and it's not really very easy to
understand why those changes are necessary. My comments above about
splitting the patch into a series of patches that can potentially be
reviewed and applied independently, with the main patch being the last
in the series, are a suggestion as to how to tackle that. There might
be some work that needs to or could be done on the comments, too. For
example, the patch splits out add_paths_to_append_rel from
set_append_rel_pathlist, but the comments don't say anything helpful
like "we need to do X after Y, because Z". They just say that we do
it. To some extent I think the comments in the optimizer have that
problem generally, so it's not entirely the fault of this patch;
still, the lack of those explanations makes the code reorganization
harder to follow, and might confuse future patch authors, too.
Specifically about add_paths_to_append_rel(), what do you expect the
comment to say? It would be obvious why we split that functionality
into a separate function: in fact, we don't necessarily explain why
certain code resides in a separate function in the comments. I think,
that particular comment (or for that matter other such comments in the
optimizer) can be removed altogether, since it just writes the
function names as an "English" sentence. I sometimes find those
comments useful, because I can read just those comments and forget
about the code, making comprehension easy. If highlighting is ON, your
brain habitually ignores the non-comment portions when required. I am
open to suggestions.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
0001-Refactor-set_append_rel_pathlist.patchapplication/octet-stream; name=0001-Refactor-set_append_rel_pathlist.patchDownload
From cf978fcadc1985c27783c114b8a367fe795efe9e Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 14:45:37 +0530
Subject: [PATCH 01/11] Refactor set_append_rel_pathlist.
set_append_rel_pathlist() creates paths for each child relation and then
creates append paths for the "append" relation. Right now only a base relation
can have children, but with partition-wise join and aggregation a join or an
upper relation can have children as well. While the code to add paths to the
child relations differs for base, join and upper child relations, the code to
create append paths can be shared by all the three relations. Hence separating
it into a new function add_paths_to_append_rel() so that it can be re-used for
all kinds of relations.
---
src/backend/optimizer/path/allpaths.c | 51 ++++++++++++++++++++++++++-------
1 file changed, 41 insertions(+), 10 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 5c18987..d797d6a 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -127,6 +127,8 @@ static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
static int compute_parallel_worker(RelOptInfo *rel, BlockNumber pages);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels);
/*
@@ -1169,19 +1171,11 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
* Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
@@ -1189,7 +1183,6 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -1224,6 +1217,44 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ /* Add Append/MergeAppend paths to the "append" relation. */
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+
+/*
+ * add_paths_to_append_rel
+ * Generate Append/MergeAppend paths for given "append" relation.
+ *
+ * The function collects all parameterizations and orderings supported by the
+ * non-dummy children. For every such parameterization or ordering, it creates
+ * an append path collecting one path from each non-dummy child with given
+ * parameterization or ordering. Similarly it collects partial paths from
+ * non-dummy children to create partial append paths.
+ */
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid = true;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
--
1.7.9.5
0002-Refactor-make_join_rel.patchapplication/octet-stream; name=0002-Refactor-make_join_rel.patchDownload
From 80861ce9a56d639833f015392bb6d4035a9deda2 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 15:41:39 +0530
Subject: [PATCH 02/11] Refactor make_join_rel().
The code in make_join_rel() to add paths to join relation for a given pair of
joining relations can be re-used to add paths to a child join relation, which
do not need the other functionality offered by make_join_rel(). Separate this
code into populate_joinrel_with_paths(). This patch does just refactors
make_join_rel() to pave the way for partition-wise join.
---
src/backend/optimizer/path/joinrels.c | 28 ++++++++++++++++++++++++----
1 file changed, 24 insertions(+), 4 deletions(-)
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 6f3c20b..936ee0c 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -32,6 +32,9 @@ static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
/*
@@ -724,6 +727,27 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Add paths to the given joinrel for given pair of joining relations. The
+ * SpecialJoinInfo provides details about the join and the restrictlist
+ * contains the join clauses and the other clauses applicable for given pair
+ * of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
@@ -868,10 +892,6 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
--
1.7.9.5
0003-Refactor-adjust_appendrel_attrs.patchapplication/octet-stream; name=0003-Refactor-adjust_appendrel_attrs.patchDownload
From 74d38c91f9c37f8c6ede2a1a63ae3fec6731a10d Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 17:22:52 +0530
Subject: [PATCH 03/11] Refactor adjust_appendrel_attrs.
adjust_appendrel_attrs() is used to translate nodes for a parent relation to
those for a child relation by replacing the parent specific nodes like Var
nodes with corresponding nodes specific to the child. Right now this function
works with a single parent-child pair. For partition-wise join and
partition-wise aggregation/grouping, we require to translate nodes for multiple
parent-child pairs. This patch modifies adjust_appendrel_attrs() to work with
multiple parent-child pairs.
---
src/backend/optimizer/path/allpaths.c | 7 +-
src/backend/optimizer/path/equivclass.c | 2 +-
src/backend/optimizer/plan/planner.c | 2 +-
src/backend/optimizer/prep/prepunion.c | 161 ++++++++++++++++++++++---------
src/include/optimizer/prep.h | 2 +-
5 files changed, 121 insertions(+), 53 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index d797d6a..d8fac14 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -862,6 +862,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
ListCell *parentvars;
ListCell *childvars;
ListCell *lc;
+ List *appinfo_list = list_make1(appinfo);
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -903,7 +904,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Assert(IsA(rinfo, RestrictInfo));
childqual = adjust_appendrel_attrs(root,
(Node *) rinfo->clause,
- appinfo);
+ appinfo_list);
childqual = eval_const_expressions(root, childqual);
/* check for flat-out constant */
if (childqual && IsA(childqual, Const))
@@ -1022,11 +1023,11 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
- appinfo);
+ appinfo_list);
childrel->reltarget->exprs = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->reltarget->exprs,
- appinfo);
+ appinfo_list);
/*
* We have to make child entries in the EquivalenceClass data
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index a329dd1..bcce142 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2111,7 +2111,7 @@ add_child_rel_equivalences(PlannerInfo *root,
child_expr = (Expr *)
adjust_appendrel_attrs(root,
(Node *) cur_em->em_expr,
- appinfo);
+ list_make1(appinfo));
/*
* Transform em_relids to match. Note we do *not* do
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 881742f..24a48b8 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -1085,7 +1085,7 @@ inheritance_planner(PlannerInfo *root)
subroot->parse = (Query *)
adjust_appendrel_attrs(root,
(Node *) parse,
- appinfo);
+ list_make1(appinfo));
/*
* If there are securityQuals attached to the parent, move them to the
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 06e843d..6f41979 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -55,7 +55,7 @@
typedef struct
{
PlannerInfo *root;
- AppendRelInfo *appinfo;
+ List *appinfos;
} adjust_appendrel_attrs_context;
static Path *recurse_set_operations(Node *setOp, PlannerInfo *root,
@@ -107,9 +107,9 @@ static Bitmapset *translate_col_privs(const Bitmapset *parent_privs,
List *translated_vars);
static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
-static Relids adjust_relid_set(Relids relids, Index oldrelid, Index newrelid);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
+static Relids adjust_relid_set(Relids relids, List *append_rel_infos);
/*
@@ -1719,10 +1719,10 @@ translate_col_privs(const Bitmapset *parent_privs,
/*
* adjust_appendrel_attrs
- * Copy the specified query or expression and translate Vars referring
- * to the parent rel of the specified AppendRelInfo to refer to the
- * child rel instead. We also update rtindexes appearing outside Vars,
- * such as resultRelation and jointree relids.
+ * Copy the specified query or expression and translate Vars referring to
+ * the parent rels of the specified in the given list of AppendRelInfos to
+ * refer to the corresponding child rel instead. We also update rtindexes
+ * appearing outside Vars, such as resultRelation and jointree relids.
*
* Note: this is only applied after conversion of sublinks to subplans,
* so we don't need to cope with recursion into sub-queries.
@@ -1731,13 +1731,20 @@ translate_col_privs(const Bitmapset *parent_privs,
* maybe we should try to fold the two routines together.
*/
Node *
-adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
+adjust_appendrel_attrs(PlannerInfo *root, Node *node, List *appinfos)
{
Node *result;
adjust_appendrel_attrs_context context;
+ ListCell *lc;
context.root = root;
- context.appinfo = appinfo;
+ context.appinfos = appinfos;
+
+ /*
+ * Catch a caller who wants to adjust expressions, but doesn't pass any
+ * AppendRelInfo.
+ */
+ Assert(appinfos && list_length(appinfos) >= 1);
/*
* Must be prepared to start with a Query or a bare expression tree.
@@ -1745,20 +1752,28 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
if (node && IsA(node, Query))
{
Query *newnode;
+ AppendRelInfo *appinfo;
newnode = query_tree_mutator((Query *) node,
adjust_appendrel_attrs_mutator,
(void *) &context,
QTW_IGNORE_RC_SUBQUERIES);
- if (newnode->resultRelation == appinfo->parent_relid)
+ foreach (lc, appinfos)
{
- newnode->resultRelation = appinfo->child_relid;
- /* Fix tlist resnos too, if it's inherited UPDATE */
- if (newnode->commandType == CMD_UPDATE)
- newnode->targetList =
- adjust_inherited_tlist(newnode->targetList,
- appinfo);
+ appinfo = lfirst(lc);
+
+ if (newnode->resultRelation == appinfo->parent_relid)
+ {
+ newnode->resultRelation = appinfo->child_relid;
+ /* Fix tlist resnos too, if it's inherited UPDATE */
+ if (newnode->commandType == CMD_UPDATE)
+ newnode->targetList =
+ adjust_inherited_tlist(newnode->targetList,
+ appinfo);
+ break;
+ }
}
+
result = (Node *) newnode;
}
else
@@ -1771,13 +1786,29 @@ static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
- AppendRelInfo *appinfo = context->appinfo;
+ List *appinfos = context->appinfos;
+ ListCell *lc;
+
+ /*
+ * Catch a caller who wants to adjust expressions, but doesn't pass any
+ * AppendRelInfo.
+ */
+ Assert(appinfos && list_length(appinfos) >= 1);
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
Var *var = (Var *) copyObject(node);
+ AppendRelInfo *appinfo;
+
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (var->varno == appinfo->parent_relid)
+ break;
+ }
if (var->varlevelsup == 0 &&
var->varno == appinfo->parent_relid)
@@ -1860,29 +1891,54 @@ adjust_appendrel_attrs_mutator(Node *node,
{
CurrentOfExpr *cexpr = (CurrentOfExpr *) copyObject(node);
- if (cexpr->cvarno == appinfo->parent_relid)
- cexpr->cvarno = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (cexpr->cvarno == appinfo->parent_relid)
+ {
+ cexpr->cvarno = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) cexpr;
}
if (IsA(node, RangeTblRef))
{
RangeTblRef *rtr = (RangeTblRef *) copyObject(node);
- if (rtr->rtindex == appinfo->parent_relid)
- rtr->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (rtr->rtindex == appinfo->parent_relid)
+ {
+ rtr->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) rtr;
}
if (IsA(node, JoinExpr))
{
/* Copy the JoinExpr node with correct mutation of subnodes */
JoinExpr *j;
+ AppendRelInfo *appinfo;
j = (JoinExpr *) expression_tree_mutator(node,
adjust_appendrel_attrs_mutator,
(void *) context);
/* now fix JoinExpr's rtindex (probably never happens) */
- if (j->rtindex == appinfo->parent_relid)
- j->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (j->rtindex == appinfo->parent_relid)
+ {
+ j->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) j;
}
if (IsA(node, PlaceHolderVar))
@@ -1895,9 +1951,7 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == 0)
- phv->phrels = adjust_relid_set(phv->phrels,
- appinfo->parent_relid,
- appinfo->child_relid);
+ phv->phrels = adjust_relid_set(phv->phrels, context->appinfos);
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1929,23 +1983,17 @@ adjust_appendrel_attrs_mutator(Node *node,
/* adjust relid sets too */
newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
/*
* Reset cached derivative fields, since these might need to have
@@ -1977,19 +2025,38 @@ adjust_appendrel_attrs_mutator(Node *node,
}
/*
- * Substitute newrelid for oldrelid in a Relid set
+ * Replace parent relids by child relids in the copy of given relid set
+ * according to the given list of AppendRelInfos. The given relid set is
+ * returned as is if it contains no parent in the given list, otherwise, the
+ * given relid set is not changed.
*/
-static Relids
-adjust_relid_set(Relids relids, Index oldrelid, Index newrelid)
+Relids
+adjust_relid_set(Relids relids, List *append_rel_infos)
{
- if (bms_is_member(oldrelid, relids))
+ ListCell *lc;
+ Bitmapset *result = NULL;
+
+ foreach (lc, append_rel_infos)
{
- /* Ensure we have a modifiable copy */
- relids = bms_copy(relids);
- /* Remove old, add new */
- relids = bms_del_member(relids, oldrelid);
- relids = bms_add_member(relids, newrelid);
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ /* Remove parent, add child */
+ if (bms_is_member(appinfo->parent_relid, relids))
+ {
+ /* Make a copy if we are changing the set. */
+ if (!result)
+ result = bms_copy(relids);
+
+ result = bms_del_member(result, appinfo->parent_relid);
+ result = bms_add_member(result, appinfo->child_relid);
+ }
}
+
+ /* Return new set if we modified the given set. */
+ if (result)
+ return result;
+
+ /* Else return the given relids set as is. */
return relids;
}
@@ -2110,5 +2177,5 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
else
Assert(parent_rel->reloptkind == RELOPT_BASEREL);
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, appinfo);
+ return adjust_appendrel_attrs(root, node, list_make1(appinfo));
}
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index 2b20b36..a02e06a 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -53,7 +53,7 @@ extern RelOptInfo *plan_set_operations(PlannerInfo *root);
extern void expand_inherited_tables(PlannerInfo *root);
extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
- AppendRelInfo *appinfo);
+ List *appinfos);
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
--
1.7.9.5
0004-Refactor-build_join_rel.patchapplication/octet-stream; name=0004-Refactor-build_join_rel.patchDownload
From 5606e2526b997606e8485c00fc34ac1f5ccf2fe9 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Mon, 6 Feb 2017 10:58:48 +0530
Subject: [PATCH 04/11] Refactor build_join_rel.
Partition-wise joins do not use build_join_rel() to build child-join relations,
but it still requires code to set foreign relation properties as well as code
to add join relation into PlannerInfo. Separate that code into
set_foreign_rel_properties() and add_join_rel() resp. to be called while
building child joins.
---
src/backend/optimizer/util/relnode.c | 142 ++++++++++++++++++++--------------
1 file changed, 83 insertions(+), 59 deletions(-)
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index adc1db9..160ed6d 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -49,6 +49,9 @@ static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
/*
@@ -327,6 +330,82 @@ find_join_rel(PlannerInfo *root, Relids relids)
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
+ * add_join_rel
+ * Add given join relation to the list of join relations in the given
+ * PlannerInfo. Also add it to the auxiliary hashtable if there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
@@ -424,46 +503,8 @@ build_join_rel(PlannerInfo *root,
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Compute information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
@@ -531,25 +572,8 @@ build_join_rel(PlannerInfo *root,
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
--
1.7.9.5
0005-Add-function-find_param_path_info.patchapplication/octet-stream; name=0005-Add-function-find_param_path_info.patchDownload
From ec2984ab4ea387d5e91fbd354209ff45f114b603 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Mon, 6 Feb 2017 12:14:06 +0530
Subject: [PATCH 05/11] Add function find_param_path_info.
The code to search ParamPathInfo for a set of required outer relations in the
list of ParamPathInfos of a given relation is duplicated in
get_*rel_parampathinfo() functions. Separate this code into
find_param_path_info() and call it from get_*rel_parampathinfo() functions.
---
src/backend/optimizer/util/relnode.c | 46 ++++++++++++++++++++--------------
1 file changed, 27 insertions(+), 19 deletions(-)
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 160ed6d..19982dc 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -52,6 +52,8 @@ static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
static void set_foreign_rel_properties(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
/*
@@ -1047,12 +1049,8 @@ get_baserel_parampathinfo(PlannerInfo *root, RelOptInfo *baserel,
Assert(!bms_overlap(baserel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, baserel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(baserel, required_outer)))
+ return ppi;
/*
* Identify all joinclauses that are movable to this base rel given this
@@ -1289,12 +1287,8 @@ get_joinrel_parampathinfo(PlannerInfo *root, RelOptInfo *joinrel,
*restrict_clauses = list_concat(pclauses, *restrict_clauses);
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, joinrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(joinrel, required_outer)))
+ return ppi;
/* Estimate the number of rows returned by the parameterized join */
rows = get_parameterized_joinrel_size(root, joinrel,
@@ -1333,7 +1327,6 @@ ParamPathInfo *
get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
{
ParamPathInfo *ppi;
- ListCell *lc;
/* Unparameterized paths have no ParamPathInfo */
if (bms_is_empty(required_outer))
@@ -1342,12 +1335,8 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
Assert(!bms_overlap(appendrel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, appendrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(appendrel, required_outer)))
+ return ppi;
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
@@ -1358,3 +1347,22 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
return ppi;
}
+
+/*
+ * Returns a ParamPathInfo for outer relations specified by required_outer, if
+ * already available in the given rel. Returns NULL otherwise.
+ */
+ParamPathInfo *
+find_param_path_info(RelOptInfo *rel, Relids required_outer)
+{
+ ListCell *lc;
+
+ foreach(lc, rel->ppilist)
+ {
+ ParamPathInfo *ppi = (ParamPathInfo *) lfirst(lc);
+ if (bms_equal(ppi->ppi_req_outer, required_outer))
+ return ppi;
+ }
+
+ return NULL;
+}
--
1.7.9.5
0006-Canonical-partition-scheme.patchapplication/octet-stream; name=0006-Canonical-partition-scheme.patchDownload
From 53c7c239715824278c2abe19c15abdb1ed3d7d91 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 10:47:49 +0530
Subject: [PATCH 06/11] Canonical partition scheme.
For a single level partitioned table, annotate RelOptInfo of a partitioned
table with canonical partition scheme. All partitioned tables, with the same
partitioning scheme share the same canonical partitioning scheme. We store the
RelOptInfo's corresponding to the partitions in RelOptInfo of the partitioned
table. Those are arranged in the same order as the partition bound indices in
the partition scheme.
We do not handle multi-level partitioned tables since inheritance hierarchy
does not retain the partition hierarchy. All the partitions at any level
appear as children of the top-level partitioned table. Thus making it hard to
associate a partition relation with corresponding partition bounds.
Multi-level partitioned tables will be handled in a separate patch.
---
src/backend/optimizer/path/allpaths.c | 48 +++++++
src/backend/optimizer/util/plancat.c | 232 +++++++++++++++++++++++++++++++++
src/include/nodes/relation.h | 51 ++++++++
3 files changed, 331 insertions(+)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index d8fac14..0eb56f3 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -829,6 +829,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ int nparts;
/*
* Initialize to compute size estimates for whole append relation.
@@ -850,6 +851,18 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
nattrs = rel->max_attr - rel->min_attr + 1;
parent_attrsizes = (double *) palloc0(nattrs * sizeof(double));
+ /*
+ * For a partitioned table, allocate an array to hold RelOptInfo's of the
+ * partitions. It will be filled while handling the children below.
+ */
+ if (rel->part_scheme)
+ {
+ nparts = rel->part_scheme->nparts;
+ rel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+ }
+ else
+ nparts = 0;
+
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
@@ -879,6 +892,30 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
/*
+ * Two partitioned tables with the same partitioning scheme, have their
+ * partition bounds arranged in the same order. The order of partition
+ * OIDs in RelOptInfo corresponds to the partition bound order. Thus
+ * the OIDs of matching partitions from both the tables are placed at
+ * the same position in the array of partition OIDs in the respective
+ * RelOptInfos. Arranging RelOptInfos of partitions in the same order
+ * as their OIDs makes it easy to find the RelOptInfos of matching
+ * partitions for partition-wise join.
+ */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (rel->part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+ }
+
+ /*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
* baserestrictinfo quals are needed before we can check for
@@ -1130,6 +1167,17 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ if (!rel->part_rels[cnt_parts])
+ elog(ERROR, "could not find the RelOptInfo of a partition with oid %u",
+ rel->part_oids[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7836e6b..01ba885 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_inherits_fn.h"
#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "foreign/fdwapi.h"
@@ -63,6 +64,13 @@ static List *get_relation_constraints(PlannerInfo *root,
bool include_notnull);
static List *build_index_tlist(PlannerInfo *root, IndexOptInfo *index,
Relation heapRelation);
+static List **build_baserel_partition_key_exprs(Relation relation,
+ Index varno);
+static PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+static void get_relation_partition_info(PlannerInfo *root, RelOptInfo *rel,
+ Relation relation, bool inhparent);
+
/*
@@ -412,6 +420,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation, inhparent);
+ /* Collect info about relation's partitioning scheme, if any. */
+ get_relation_partition_info(root, rel, relation, inhparent);
+
heap_close(relation, NoLock);
/*
@@ -1716,3 +1727,224 @@ has_row_triggers(PlannerInfo *root, Index rti, CmdType event)
heap_close(relation, NoLock);
return result;
}
+
+/*
+ * get_relation_partition_info
+ *
+ * Retrieves partitioning information for a given relation.
+ *
+ * Partitioning scheme, partition key expressions and OIDs of partitions are
+ * added to the given RelOptInfo. A partitioned table can participate in the
+ * query as a simple relation or an inheritance parent. Only the later can have
+ * child relations, and hence partitions. From the point of view of the query
+ * optimizer only such relations are considered to be partitioned. Hence
+ * partitioning information is set only for an inheritance parent.
+ */
+static void
+get_relation_partition_info(PlannerInfo *root, RelOptInfo *rel,
+ Relation relation, bool inhparent)
+{
+ /* No partitioning information for an unpartitioned relation. */
+ if (relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE ||
+ !inhparent ||
+ !(rel->part_scheme = find_partition_scheme(root, relation)))
+ {
+ rel->partexprs = NULL;
+ rel->part_rels = NULL;
+ rel->part_oids = NULL;
+ return;
+ }
+
+ rel->partexprs = build_baserel_partition_key_exprs(relation, rel->relid);
+ rel->part_oids = RelationGetPartitionDesc(relation)->oids;
+
+ /*
+ * RelOptInfos of the partitions will be filled in when we build those for
+ * the child relations.
+ */
+ rel->part_rels = NULL;
+ return;
+}
+
+/*
+ * find_partition_scheme
+ *
+ * The function returns a canonical partition scheme which exactly matches the
+ * partitioning properties of the given relation if one exists in the of
+ * canonical partitioning schemes maintained in PlannerInfo. If none of the
+ * existing partitioning schemes match, the function creates a canonical
+ * partition scheme and adds it to the list.
+ *
+ * For an unpartitioned table or for a multi-level partitioned table it returns
+ * NULL. See comments in the function for more details.
+ */
+static PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ int cnt_parts;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /*
+ * For a multi-level partitioned table, we do not retain the partitioning
+ * hierarchy while expanding RTE for the topmost parent. Thus the number of
+ * children as per root->append_rel_list does not match the number of
+ * partitions specified in the partition descriptor and hence the
+ * partitioning scheme of a multi-partitioned table does not reflect the
+ * true picture. So for now, treat a multi-partitioned table as not
+ * partitioned.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (has_subclass(part_desc->oids[cnt_parts]))
+ return NULL;
+ }
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * For types, it suffices to match the type id, mod and collation;
+ * len, byval and align are depedent on the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->parttypid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->parttypmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->parttypcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->boundinfo,
+ part_scheme->boundinfo))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->boundinfo = part_desc->boundinfo;
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopfamily, part_key->partopfamily,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopcintype, part_key->partopcintype,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_types, part_key->parttypid,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ memcpy(part_scheme->key_typmods, part_key->parttypmod,
+ sizeof(int32) * partnatts);
+
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_collations, part_key->parttypcoll,
+ sizeof(Oid) * partnatts);
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_key_exprs
+ *
+ * Collect partition key expressions for a given base relation. The function
+ * converts any single column partition keys into corresponding Var nodes. It
+ * restamps Var nodes in partition key expressions by given varno. The
+ * partition key expressions are returned as an array of single element Lists
+ * to be stored in RelOptInfo of the base relation.
+ */
+static List **
+build_baserel_partition_key_exprs(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (lc == NULL)
+ elog(ERROR, "wrong number of partition key expressions");
+
+ /* Re-stamp the expressions with given varno. */
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 643be54..4f99184 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -15,6 +15,7 @@
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
@@ -261,6 +262,9 @@ typedef struct PlannerInfo
List *distinct_pathkeys; /* distinctClause pathkeys, if any */
List *sort_pathkeys; /* sortClause pathkeys, if any */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
List *initial_rels; /* RelOptInfos we are now trying to join */
/* Use fetch_upper_rel() to get any particular upper rel */
@@ -321,6 +325,38 @@ typedef struct PlannerInfo
((root)->simple_rte_array ? (root)->simple_rte_array[rti] : \
rt_fetch(rti, (root)->parse->rtable))
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting may be partitioned in the same way as the underlying
+ * scan relations. All such relations partitioned in the same way share the
+ * partitioning scheme.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ PartitionBoundInfo boundinfo; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
+typedef struct PartitionSchemeData *PartitionScheme;
/*----------
* RelOptInfo
@@ -531,6 +567,7 @@ typedef struct RelOptInfo
PlannerInfo *subroot; /* if subquery */
List *subplan_params; /* if subquery */
int rel_parallel_workers; /* wanted number of parallel workers */
+ Oid *part_oids; /* OIDs of partitions */
/* Information about foreign tables and foreign joins */
Oid serverid; /* identifies server for the table or join */
@@ -549,6 +586,20 @@ typedef struct RelOptInfo
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For all the partitioned relations. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there may be as many elements
+ * as the number of joining
+ * relations.
+ */
} RelOptInfo;
/*
--
1.7.9.5
0007-Partition-wise-join-tests.patchapplication/octet-stream; name=0007-Partition-wise-join-tests.patchDownload
From 82e4452ff549ede9f34684d363f66291a3bb632b Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 11:57:30 +0530
Subject: [PATCH 07/11] Partition-wise join tests.
This file does not contain tests for joins between multi-leveled partitioned
tables. Those will be added later.
---
src/test/regress/expected/partition_join.out | 4114 ++++++++++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/serial_schedule | 1 +
src/test/regress/sql/partition_join.sql | 515 ++++
4 files changed, 4631 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/partition_join.out
create mode 100644 src/test/regress/sql/partition_join.sql
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..18238fa
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,4114 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(47 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t2.a, t2.b
+ Sort Key: t1_3.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Sort Key: t1_4.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Sort Key: t1_5.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Sort Key: t1_3.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Sort Key: t1_4.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Sort Key: t1_5.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1_2.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(43 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(44 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+--
+-- negative testcases
+--
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index edeb2d6..ac38f50 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -103,7 +103,7 @@ test: publication subscription
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 27a46d7..1bf98a4 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -172,3 +172,4 @@ test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..0322f1e
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,515 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- negative testcases
+--
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
--
1.7.9.5
0008-Partition-wise-join.patchapplication/octet-stream; name=0008-Partition-wise-join.patchDownload
From b9ceb880a2377ae2570a3fb2aa4f862d5b8846fd Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 16:04:03 +0530
Subject: [PATCH 08/11] Partition-wise join
Implement partition-wise join for join between single level partitioned tables.
The details of this technique can be found in optimizer/README, where most of
the implementation has been explained.
We obtain clauses applicable to a child-join by translating corresponding
clauses of the parent. Because child-join can be computed by different
combinations of joining child relations, a given clause is required to be
translated multiple times. In order to reduce the memory consumption, we keep a
repository of child-clauses derived from a parent clause and search in that
repository before translating.
Tests for semi-join, those forcing a merge join for child-join and those
testing lateral join will crash with this patch. The tests testing joins with
partition pruning will also fail. Those crashes and failures are because the
existing code does not expect a child-join to appear in certain cases.
Following patches will fix that code.
---
src/backend/nodes/copyfuncs.c | 9 +
src/backend/optimizer/README | 53 ++++
src/backend/optimizer/path/allpaths.c | 305 ++++++++++++++++---
src/backend/optimizer/path/costsize.c | 3 +
src/backend/optimizer/path/joinpath.c | 21 +-
src/backend/optimizer/path/joinrels.c | 421 ++++++++++++++++++++++++++
src/backend/optimizer/plan/createplan.c | 227 +++++++++++++-
src/backend/optimizer/prep/prepunion.c | 160 ++++++++++
src/backend/optimizer/util/pathnode.c | 113 +++++++
src/backend/optimizer/util/placeholder.c | 55 ++++
src/backend/optimizer/util/relnode.c | 266 +++++++++++++++-
src/backend/utils/misc/guc.c | 28 ++
src/include/nodes/nodes.h | 1 +
src/include/nodes/relation.h | 57 ++++
src/include/optimizer/cost.h | 5 +
src/include/optimizer/pathnode.h | 6 +
src/include/optimizer/paths.h | 5 +
src/include/optimizer/placeholder.h | 2 +
src/include/optimizer/prep.h | 8 +
src/test/regress/expected/partition_join.out | 4 +
src/test/regress/expected/sysviews.out | 29 +-
src/test/regress/sql/partition_join.sql | 5 +
22 files changed, 1713 insertions(+), 70 deletions(-)
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 30d733e..72c021e 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2070,6 +2070,15 @@ _copyRestrictInfo(const RestrictInfo *from)
COPY_SCALAR_FIELD(left_bucketsize);
COPY_SCALAR_FIELD(right_bucketsize);
+ /*
+ * Do not copy parent_rinfo and child_rinfos because 1. they create a
+ * circular dependency between child and parent RestrictInfo 2. dropping
+ * those links just means that we loose some memory optimizations. 3. There
+ * is a possibility that the child and parent RestrictInfots themselves may
+ * have got copied and thus the old links may no longer be valid. The
+ * caller may set up those links itself, if needed.
+ */
+
return newnode;
}
diff --git a/src/backend/optimizer/README b/src/backend/optimizer/README
index fc0fca4..7565ae4 100644
--- a/src/backend/optimizer/README
+++ b/src/backend/optimizer/README
@@ -1076,3 +1076,56 @@ be desirable to postpone the Gather stage until as near to the top of the
plan as possible. Expanding the range of cases in which more work can be
pushed below the Gather (and costing them accurately) is likely to keep us
busy for a long time to come.
+
+Partition-wise joins
+--------------------
+A join between two similarly partitioned tables can be broken down into joins
+between their matching partitions if there exists an equi-join condition
+between the partition keys of the joining tables. The equi-join between
+partition keys implies that for a given row in a given partition of a given
+partitioned table, its joining row, if exists, should exist only in the
+matching partition of the other partitioned table; no row from non-matching
+partitions in the other partitioned table can join with the given row from the
+first table. This condition allows the join between partitioned table to be
+broken into joins between the matching partitions. The resultant join is
+partitioned in the same way as the joining relations, thus allowing an N-way
+join between similarly partitioned tables having equi-join condition between
+their partition keys to be broken down into N-way joins between their matching
+partitions. This technique of breaking down a join between partition tables
+into join between their partitions is called partition-wise join. We will use
+term "partitioned relation" for both partitioned table as well as join between
+partitioned tables which can use partition-wise join technique.
+
+Partitioning properties of a partitioned table are stored in
+PartitionSchemeData structure. Planner maintains a list of canonical partition
+schemes (distinct PartitionSchemeData objects) so that any two partitioned
+relations with same partitioning scheme share the same PartitionSchemeData
+object. This reduces memory consumed by PartitionSchemeData objects and makes
+it easy to compare the partition schemes of joining relations. RelOptInfos of
+partitioned relations hold partition key expressions and the RelOptInfos of
+the partition relations of that relation.
+
+Partition-wise joins are planned in two phases
+
+1. First phase creates the RelOptInfos for joins between matching partitions,
+henceforth referred to as child-joins. The number of paths created for a
+child-join i.e. join between partitions is same as the number of paths created
+for join between parents. That number grows exponentially with the number of
+base relations being joined. The time and memory consumed to create paths for
+each child-join will be proporional to the number of partitions. This will not
+scale well with thousands of partitions. Instead of that we estimate
+partition-wise join cost based on the costs of sampled child-joins. We choose
+child-joins with higher sizes to have realistic estimates. If the number of
+sampled child-joins is same as the number of live child-joins, we create append
+paths as we know costs of all required child-joins. Otherwise we create
+PartitionJoinPaths with cost estimates based on the costs of sampled
+child-joins. While creating append paths or PartitionJoin paths we create paths
+for all the different possible parameterizations and pathkeys available in the
+sampled child-joins.
+
+2. If PartitionJoinPath emerges as the best possible path, we create paths for
+each unsampled child-join. From every child-join we choose the cheapest path
+with same parameterization or pathkeys as the PartitionJoinPath. This path is
+converted into a plan and all the child-join plans are combined using an Append
+or MergeAppend plan as appropriate. We use a fresh memory context for planning
+each unsampled child-join, thus reducing memory consumption.
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 0eb56f3..1adf6ba 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -15,6 +15,7 @@
#include "postgres.h"
+#include "miscadmin.h"
#include <limits.h>
#include <math.h>
@@ -93,8 +94,8 @@ static void set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
static void set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
static void generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels,
- List *all_child_pathkeys);
+ List *live_childrels, List *all_child_pathkeys,
+ bool partition_join_path);
static Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
RelOptInfo *rel,
Relids required_outer);
@@ -128,8 +129,8 @@ static void recurse_push_qual(Node *setOp, Query *topquery,
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
static int compute_parallel_worker(RelOptInfo *rel, BlockNumber pages);
static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels);
-
+ List *live_childrels, bool partition_join_path);
+static int compare_rel_size(const void *rel1_p, const void *rel2_p);
/*
* make_one_rel
@@ -891,6 +892,12 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel = find_base_rel(root, childRTindex);
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ /* Pass top parent's relids down the inheritance hierarchy. */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
/*
* Two partitioned tables with the same partitioning scheme, have their
* partition bounds arranged in the same order. The order of partition
@@ -900,10 +907,15 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* RelOptInfos. Arranging RelOptInfos of partitions in the same order
* as their OIDs makes it easy to find the RelOptInfos of matching
* partitions for partition-wise join.
+ *
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for building
+ * child-join targetlists.
*/
if (rel->part_scheme)
{
int cnt_parts;
+ AttrNumber attno;
for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
{
@@ -913,6 +925,38 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
rel->part_rels[cnt_parts] = childrel;
}
}
+
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /*
+ * Parent Var for a user defined attribute translates to
+ * child Var.
+ */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
}
/*
@@ -1057,10 +1101,8 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* PlaceHolderVars.) XXX we do not bother to update the cost or width
* fields of childrel->reltarget; not clear if that would be useful.
*/
- childrel->joininfo = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->joininfo,
- appinfo_list);
+ childrel->joininfo = build_child_clauses(root, rel->joininfo,
+ appinfo_list);
childrel->reltarget->exprs = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->reltarget->exprs,
@@ -1079,14 +1121,6 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
- * Note: we could compute appropriate attr_needed data for the child's
- * variables, by transforming the parent's attr_needed through the
- * translated_vars mapping. However, currently there's no need
- * because attr_needed is only examined for base relations not
- * otherrels. So we just leave the child's attr_needed empty.
- */
-
- /*
* If parallelism is allowable for this query in general, see whether
* it's allowable for this childrel in particular. But if we've
* already decided the appendrel is not parallel-safe as a whole,
@@ -1269,10 +1303,9 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
/* Add Append/MergeAppend paths to the "append" relation. */
- add_paths_to_append_rel(root, rel, live_childrels);
+ add_paths_to_append_rel(root, rel, live_childrels, false);
}
-
/*
* add_paths_to_append_rel
* Generate Append/MergeAppend paths for given "append" relation.
@@ -1282,20 +1315,44 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* an append path collecting one path from each non-dummy child with given
* parameterization or ordering. Similarly it collects partial paths from
* non-dummy children to create partial append paths.
+ *
+ * When called on partitioned join relation with partition_join_path = true, it
+ * adds PartitionJoinPath instead of Merge/Append path. This path is costed
+ * based on the costs of sampled child-join and is expanded later into
+ * Merge/Append plan.
*/
static void
add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels)
+ List *live_childrels, bool partition_join_path)
{
List *subpaths = NIL;
bool subpaths_valid = true;
List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
+ bool partial_subpaths_valid;
List *all_child_pathkeys = NIL;
List *all_child_outers = NIL;
ListCell *l;
/*
+ * While creating PartitionJoinPath, we sample paths from only a few child
+ * relations. Even if all of sampled children have partial paths, it's not
+ * guaranteed that all the unsampled children will have partial paths.
+ * Hence we do not create partial PartitionJoinPaths.
+ */
+ partial_subpaths_valid = !partition_join_path ? true : false;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (live_childrels == NIL)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
* For every non-dummy child, remember the cheapest path. Also, identify
* all pathkeys (orderings) and parameterizations (required_outer sets)
* available for the non-dummy member relations.
@@ -1394,7 +1451,17 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel, subpaths,
+ NULL, NIL);
+ else
+ path = (Path *) create_append_path(rel, subpaths, NULL, 0);
+
+ add_path(rel, path);
+ }
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1405,6 +1472,8 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
ListCell *lc;
int parallel_workers = 0;
+ Assert(!partition_join_path);
+
/*
* Decide on the number of workers to request for this append path.
* For now, we just use the maximum value from among the members. It
@@ -1431,7 +1500,7 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
*/
if (subpaths_valid)
generate_mergeappend_paths(root, rel, live_childrels,
- all_child_pathkeys);
+ all_child_pathkeys, partition_join_path);
/*
* Build Append paths for each parameterization seen among the child rels.
@@ -1472,8 +1541,18 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel, subpaths,
+ required_outer, NIL);
+ else
+ path = (Path *) create_append_path(rel, subpaths,
+ required_outer, 0);
+
+ add_path(rel, path);
+ }
}
}
@@ -1499,11 +1578,16 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
* parameterized mergejoin plans, it might be worth adding support for
* parameterized MergeAppends to feed such joins. (See notes in
* optimizer/README for why that might not ever happen, though.)
+ *
+ * When called on partitioned join relation with partition_join_path = true, it
+ * adds PartitionJoinPath with pathkeys instead of MergeAppend path. This path
+ * is costed based on the costs of sampled child-join and is expanded later
+ * into MergeAppend plan.
*/
static void
generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *live_childrels,
- List *all_child_pathkeys)
+ List *all_child_pathkeys, bool partition_join_path)
{
ListCell *lcp;
@@ -1514,6 +1598,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *total_subpaths = NIL;
bool startup_neq_total = false;
ListCell *lcr;
+ Path *path;
/* Select the child paths for this ordering... */
foreach(lcr, live_childrels)
@@ -1560,18 +1645,29 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
accumulate_append_subpath(total_subpaths, cheapest_total);
}
- /* ... and build the MergeAppend paths */
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- startup_subpaths,
- pathkeys,
- NULL));
+ /* ... and build the paths */
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel,
+ startup_subpaths,
+ NULL, pathkeys);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+
if (startup_neq_total)
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- total_subpaths,
- pathkeys,
- NULL));
+ {
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel,
+ total_subpaths,
+ NULL, pathkeys);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ total_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+ }
}
}
@@ -2316,8 +2412,17 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
- * join_search_one_level. After that, we're done creating paths for
- * the joinrel, so run set_cheapest().
+ * join_search_one_level.
+ *
+ * Similarly, create paths for joinrels which used partition-wise join
+ * technique. generate_partition_wise_join_paths() creates paths for
+ * only few of the child-joins with highest sizes. Though we calculate
+ * size of a child-join only once; when it gets created, it may be
+ * deemed empty while considering various join orders within
+ * join_search_one_level.
+ *
+ * After that, we're done creating paths for the joinrel, so run
+ * set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
@@ -2326,6 +2431,9 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
+ /* Create paths for partition-wise joins. */
+ generate_partition_wise_join_paths(root, rel);
+
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
@@ -3011,6 +3119,127 @@ compute_parallel_worker(RelOptInfo *rel, BlockNumber pages)
return parallel_workers;
}
+/*
+ * Function to compare estimated sizes of two relations to be used with
+ * qsort().
+ */
+static int
+compare_rel_size(const void *rel1_p, const void *rel2_p)
+{
+ RelOptInfo *rel1 = *(RelOptInfo **) rel1_p;
+ RelOptInfo *rel2 = *(RelOptInfo **) rel2_p;
+
+ return (int) (rel1->rows - rel2->rows);
+}
+
+/*
+ * generate_partition_wise_join_paths
+ *
+ * Create paths representing partition-wise join for given partitioned
+ * join relation.
+ *
+ * The number of paths created for a child-join is same as the number of paths
+ * created for join between parents. That number grows exponentially with the
+ * number of base relations being joined. The time and memory consumed to
+ * create paths for each child-join will be proporional to the number of
+ * partitions. This will not scale well with thousands of partitions. Instead
+ * of that we estimate partition-wise join cost based on the costs of sampled
+ * child-joins. We choose child-joins with higher sizes to have realistic
+ * estimates.
+ *
+ * This must be called after we have considered all joining orders since
+ * certain join orders may allow us to deem a child-join as dummy.
+ */
+void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *sampled_children = NIL;
+ int cnt_parts;
+ int num_part_to_plan;
+ int num_parts;
+ bool partition_join_path = false;
+ int num_dummy_parts = 0;
+ RelOptInfo **ordered_part_rels;
+
+ /* Handle only join relations. */
+ if (!IS_JOIN_REL(rel))
+ return;
+
+ /*
+ * If none of the join orders for this relation could use partition-wise
+ * join technique, the join is not partitioned. Reset the partitioning
+ * scheme.
+ */
+ if (!rel->part_rels)
+ rel->part_scheme = NULL;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || IS_DUMMY_REL(rel))
+ return;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ num_parts = rel->part_scheme->nparts;
+
+ /* Calculate number of child-joins to sample. */
+ num_part_to_plan = num_parts * sample_partition_fraction;
+ if (num_part_to_plan < 1)
+ num_part_to_plan = 1;
+
+ /* Order the child-join relations by their size. */
+ ordered_part_rels = (RelOptInfo **) palloc(sizeof(RelOptInfo *) *
+ num_parts);
+ memcpy(ordered_part_rels, rel->part_rels,
+ sizeof(RelOptInfo *) * num_parts);
+ qsort(ordered_part_rels, num_parts, sizeof(RelOptInfo *),
+ compare_rel_size);
+
+ /*
+ * Create paths for the child-joins for required number of largest
+ * relations. qsort() returns relations ordered in ascending sizes, so
+ * start from the end of the array.
+ */
+ for (cnt_parts = num_parts - 1; cnt_parts >= 0; cnt_parts--)
+ {
+ RelOptInfo *child_rel = rel->part_rels[cnt_parts];
+
+ /* Create paths for this child. */
+ add_paths_to_child_joinrel(root, rel, cnt_parts);
+
+ /* Dummy children will not be scanned, so ingore those. */
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ sampled_children = lappend(sampled_children, child_rel);
+
+ if (list_length(sampled_children) >= num_part_to_plan)
+ break;
+ }
+ pfree(ordered_part_rels);
+
+ /*
+ * If the number of samples is same as the number of live children, an
+ * append path will do. Otherwise, we will cost the partition-wise join
+ * based on the sampled children using PartitionJoinPath.
+ */
+ if (num_part_to_plan < num_parts - num_dummy_parts)
+ partition_join_path = true;
+
+ /* Add paths for partition-wise join based on the sampled children. */
+ add_paths_to_append_rel(root, rel, sampled_children, partition_join_path);
+
+ if (sampled_children)
+ list_free(sampled_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index a43daa7..c720115 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,9 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
+double partition_wise_plan_weight = DEFAULT_PARTITION_WISE_PLAN_WEIGHT;
+double sample_partition_fraction = DEFAULT_SAMPLE_PARTITION_FRACTION;
typedef struct
{
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index 2897245..f80fb25 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -96,6 +96,19 @@ add_paths_to_joinrel(PlannerInfo *root,
JoinPathExtraData extra;
bool mergejoin_allowed = true;
ListCell *lc;
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between child relations, even if there is a SpecialJoinInfo node for
+ * the join between the topmost parents. Hence while calculating Relids
+ * set representing the restriction, consider relids of topmost parent
+ * of partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
extra.restrictlist = restrictlist;
extra.mergeclause_list = NIL;
@@ -149,16 +162,16 @@ add_paths_to_joinrel(PlannerInfo *root,
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo2->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo2->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo2->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo2->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_righthand))
+ bms_overlap(joinrelids, sjinfo2->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_lefthand));
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 936ee0c..7476e8e 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -14,9 +14,14 @@
*/
#include "postgres.h"
+#include "miscadmin.h"
+#include "nodes/relation.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
@@ -35,6 +40,14 @@ static bool restriction_is_constant_false(List *restrictlist,
static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
RelOptInfo *rel2, RelOptInfo *joinrel,
SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
+static void free_special_join_info(SpecialJoinInfo *sjinfo);
/*
@@ -731,6 +744,9 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
restrictlist);
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
bms_free(joinrelids);
return joinrel;
@@ -1269,3 +1285,408 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
}
return false;
}
+
+/* Free memory used by SpecialJoinInfo. */
+static void
+free_special_join_info(SpecialJoinInfo *sjinfo)
+{
+ bms_free(sjinfo->min_lefthand);
+ bms_free(sjinfo->syn_lefthand);
+ bms_free(sjinfo->syn_righthand);
+ pfree(sjinfo);
+}
+
+/*
+ * Assess whether join between given two partitioned relations can be broken
+ * down into joins between matching partitions; a technique called
+ * "partition-wise join"
+ *
+ * Partition-wise join is possible when a. Joining relations have same
+ * partitioning scheme b. There exists an equi-join between the partition keys
+ * of the two relations.
+ *
+ * Partition-wise join is planned as follows (details: optimizer/README.)
+ *
+ * 1. Create the RelOptInfos for joins between matching partitions i.e
+ * child-joins and estimate sizes of those. This function is responsible for
+ * this phase.
+ *
+ * 2. Add paths representing partition-wise join. The second phase is
+ * implemented by generate_partition_wise_join_paths(). In order to save time
+ * and memory consumed in creating paths for every child-join, we create paths
+ * for only few child-joins.
+ *
+ * 3. Create merge/append plan to combining plans for every child-join,
+ * creating paths for remaining child-joins.
+ *
+ * The RelOptInfo, SpecialJoinInfo and restrictlist for each child join are
+ * obtained by translating the respective parent join structures.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ PartitionScheme part_scheme;
+ PartitionedJoin *partitioned_join;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If any of the joining parent relations is proven empty, either the join
+ * will be empty (INNER join) or will have the inner side all nullified. We
+ * take care of such cases when creating join paths for parent relations.
+ * Nothing to be done here. Also, nothing to do, if the parent join is
+ * proven empty.
+ */
+ if (IS_DUMMY_REL(rel1) || IS_DUMMY_REL(rel2) || IS_DUMMY_REL(joinrel))
+ return;
+
+ /*
+ * Partitioning scheme in join relation indicates a possibility that the
+ * join may be partitioned, but it's not necessary that every pair of
+ * joining relations can use partition-wise join technique. If one of
+ * joining relations turns out to be unpartitioned, this pair of joining
+ * relations can not use partition-wise join technique.
+ */
+ if (!rel1->part_scheme || !rel2->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, this pair of joining relations can not use
+ * partition-wise technique.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ /*
+ * The partition scheme of the join relation should match that of the
+ * joining relations.
+ */
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ /* We should have RelOptInfos of the partitions available. */
+ Assert(rel1->part_rels && rel2->part_rels);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = part_scheme->nparts;
+
+ /*
+ * We do not store information about valid pairs of joining child
+ * relations. The pair of joining relations for a child-join can be derived
+ * from valid pairs of joining parent relations. Amongst the valid pairs of
+ * parent joining relations, only those which result in partitioned join
+ * matter for partition-wise join. Remember those so that we can use them
+ * for creating paths for few child-joins in
+ * generate_partition_wise_join_paths() later.
+ */
+ partitioned_join = (PartitionedJoin *) palloc(sizeof(PartitionedJoin));
+ partitioned_join->rel1 = rel1;
+ partitioned_join->rel2 = rel2;
+ partitioned_join->sjinfo = copyObject(parent_sjinfo);
+ partitioned_join->restrictlist = parent_restrictlist;
+ joinrel->partitioned_joins = lappend(joinrel->partitioned_joins,
+ partitioned_join);
+
+ elog(DEBUG3, "join between relations %s and %s is considered for partition-wise join.",
+ bmsToString(rel1->relids), bmsToString(rel2->relids));
+
+ /* We are done if child RelOptInfos are already created. */
+ if (joinrel->part_rels)
+ return;
+
+ /* Create all the child RelOptInfos. */
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create child join relations for this partitioned join. While doing so,
+ * we estimate sizes of these child join relations. These estimates are
+ * used to find the representative child relations used for costing the
+ * partition-wise join later.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ RelOptInfo *child_joinrel;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ Assert (!joinrel->part_rels[cnt_parts]);
+
+ child_joinrel = build_child_join_rel(root, child_rel1, child_rel2,
+ joinrel, parent_sjinfo->jointype);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, parent_restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, parent_sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+ /*
+ * Set estimates of the child-joinrel's size.
+ */
+ set_joinrel_size_estimates(root, child_joinrel, child_rel1, child_rel2,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the child relations themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+}
+
+/*
+ * add_paths_to_child_join
+ * Add paths to 'child_id'th child of given parent join relation.
+ *
+ * The function creates paths for given child-join by joining corresponding
+ * children of every pair of joining parent relations which produces
+ * partitioned join. Since we create paths only for sampled child-joins, either
+ * of the children being joined may not have paths. In that case, this function
+ * is called recursively to populate paths for those.
+ */
+void
+add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
+ int child_id)
+{
+ ListCell *lc;
+ RelOptInfo *child_joinrel = parent_joinrel->part_rels[child_id];
+
+ Assert(IS_JOIN_REL(parent_joinrel));
+
+ /* If this child relation already has paths, nothing to do. */
+ if (child_joinrel->cheapest_total_path)
+ return;
+
+ /* A dummy relation will have a dummy path as the cheapest path. */
+ Assert(!is_dummy_rel(child_joinrel));
+
+ /*
+ * For every partitioned join order, calculate paths for the joining
+ * child relations and then calculate paths for given child.
+ */
+ foreach (lc, parent_joinrel->partitioned_joins)
+ {
+ PartitionedJoin *pj = lfirst(lc);
+ RelOptInfo *rel1 = pj->rel1;
+ RelOptInfo *rel2 = pj->rel2;
+ RelOptInfo *child_rel1 = rel1->part_rels[child_id];
+ RelOptInfo *child_rel2 = rel2->part_rels[child_id];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+
+ /*
+ * Add paths to joining relation if it is a join itself.
+ * Paths for child base relations are created in
+ * set_append_rel_pathlist().
+ */
+ if (IS_JOIN_REL(pj->rel1))
+ add_paths_to_child_joinrel(root, rel1, child_id);
+
+ if (IS_JOIN_REL(pj->rel2))
+ add_paths_to_child_joinrel(root, rel2, child_id);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, pj->sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, pj->restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /* Add paths for child join. */
+ populate_joinrel_with_paths(root, rel1->part_rels[child_id],
+ rel2->part_rels[child_id], child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /* Add partition-wise join paths for partitioned child-joins. */
+ generate_partition_wise_join_paths(root, child_joinrel);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+
+ set_cheapest(child_joinrel);
+}
+
+/*
+ * Returns true if there exists an equi-join condition for each pair of
+ * partition key from given relations being joined.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ /*
+ * This function should be called when the joining relations have same
+ * partitioning scheme.
+ */
+ Assert(rel1->part_scheme == rel2->part_scheme);
+ Assert(part_scheme);
+
+ num_pks = part_scheme->partnatts;
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip clauses which can not be used for a join. */
+ if (!rinfo->can_join)
+ continue;
+
+ /* Skip clauses which are not equality conditions. */
+ if (rinfo->hashjoinoperator == InvalidOid && !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+
+ /* Match the operands to the relation. */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ /*
+ * If the clause refers to different partition keys from
+ * both relations, it can not be used for partition-wise join.
+ */
+ if (ipk1 != ipk2)
+ continue;
+
+ /*
+ * The clause allows partition-wise join if only it uses the same
+ * operator family as that specified by the partition key.
+ */
+ if (!list_member_oid(rinfo->mergeopfamilies,
+ part_scheme->partopfamily[ipk1]))
+ continue;
+
+ /* Mark the partition key as having an equi-join clause. */
+ pk_has_clause[ipk1] = true;
+ }
+
+ /* Check whether every partition key has an equi-join condition. */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * Find the partition key from the given relation matching the given
+ * expression. If found, return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks;
+
+ /* This function should be called only for partitioned relations. */
+ Assert(rel->part_scheme);
+
+ num_pks = rel->part_scheme->partnatts;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() simplifies multiple
+ * RelabelType nodes into one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 997bdcf..fe6b7f8 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -42,6 +42,7 @@
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
/*
@@ -146,6 +147,8 @@ static CustomScan *create_customscan_plan(PlannerInfo *root,
static NestLoop *create_nestloop_plan(PlannerInfo *root, NestPath *best_path);
static MergeJoin *create_mergejoin_plan(PlannerInfo *root, MergePath *best_path);
static HashJoin *create_hashjoin_plan(PlannerInfo *root, HashPath *best_path);
+static Plan *create_partition_join_plan(PlannerInfo *root,
+ PartitionJoinPath *best_path);
static Node *replace_nestloop_params(PlannerInfo *root, Node *expr);
static Node *replace_nestloop_params_mutator(Node *node, PlannerInfo *root);
static void process_subquery_nestloop_params(PlannerInfo *root,
@@ -369,12 +372,20 @@ create_plan_recurse(PlannerInfo *root, Path *best_path, int flags)
(JoinPath *) best_path);
break;
case T_Append:
- plan = create_append_plan(root,
- (AppendPath *) best_path);
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root,
+ (PartitionJoinPath *)best_path);
+ else
+ plan = create_append_plan(root,
+ (AppendPath *) best_path);
break;
case T_MergeAppend:
- plan = create_merge_append_plan(root,
- (MergeAppendPath *) best_path);
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root,
+ (PartitionJoinPath *)best_path);
+ else
+ plan = create_merge_append_plan(root,
+ (MergeAppendPath *) best_path);
break;
case T_Result:
if (IsA(best_path, ProjectionPath))
@@ -3982,6 +3993,214 @@ create_hashjoin_plan(PlannerInfo *root,
return join_plan;
}
+/*
+ * create_partition_join_plan
+ * Creates Merge/Append plan consisting of join plans for child-join.
+ *
+ * Returns a Plan node.
+ */
+static Plan *
+create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
+{
+ RelOptInfo *joinrel = best_path->path.parent;
+ int nparts;
+ int cnt_parts;
+ List *child_plans = NIL;
+ List *tlist = build_path_tlist(root, &best_path->path);
+ Plan *plan;
+ MemoryContext child_context;
+ MemoryContext old_context;
+ List *pathkeys = best_path->path.pathkeys;
+ StringInfoData mem_context_name;
+
+ /* The relation should be a partitioned join relation. */
+ Assert(IS_JOIN_REL(joinrel) && joinrel->part_scheme &&
+ joinrel->partitioned_joins);
+
+ nparts = joinrel->part_scheme->nparts;
+
+ /* Create MergeAppend plan when result is expected to be ordered. */
+ if (pathkeys)
+ {
+ MergeAppend *node = makeNode(MergeAppend);
+ plan = &node->plan;
+
+ plan->targetlist = tlist;
+
+ /* Compute sorting info, and adjust MergeAppend's tlist as needed. */
+ (void) prepare_sort_from_pathkeys(plan, pathkeys,
+ best_path->path.parent->relids,
+ NULL,
+ true,
+ &node->numCols,
+ &node->sortColIdx,
+ &node->sortOperators,
+ &node->collations,
+ &node->nullsFirst);
+ }
+ else
+ {
+ Append *node = makeNode(Append);
+ plan = &node->plan;
+ plan->targetlist = tlist;
+ }
+
+ /* Fill costs, so that we can cost Sort node, if required. */
+ copy_generic_path_info(plan, (Path *) best_path);
+
+ /*
+ * Create a new memory context for planning child joins. Since this routine
+ * may be called recursively for tables with subpartitions, we use
+ * a unique context name for every level of partition by using the lowest
+ * relid amongst the base relations being joined.
+ */
+ initStringInfo(&mem_context_name);
+ appendStringInfo(&mem_context_name, "%s_%d", "ChildJoinContext",
+ bms_next_member(joinrel->relids, -1));
+ child_context = AllocSetContextCreate(CurrentMemoryContext,
+ pstrdup(mem_context_name.data),
+ ALLOCSET_DEFAULT_SIZES);
+ pfree(mem_context_name.data);
+ resetStringInfo(&mem_context_name);
+
+ /*
+ * Create a paths for all child joins, one child join at a time. The paths
+ * for every child join are independent i.e. one child does not require
+ * paths created for the other. In order to avoid accumulating memory
+ * consumed while creating paths for every child join, we use a fresh
+ * memory context for every child join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_join;
+ Path *child_path = NULL;
+ Plan *child_plan;
+ int numsortkeys;
+ AttrNumber *sortColIdx;
+ Oid *sortOperators;
+ Oid *collations;
+ bool *nullsFirst;
+
+ /*
+ * Create paths for the child join in a separate context, so that we
+ * can reuse the memory used by those paths.
+ */
+ old_context = MemoryContextSwitchTo(child_context);
+
+ add_paths_to_child_joinrel(root, joinrel, cnt_parts);
+
+ child_join = joinrel->part_rels[cnt_parts];
+
+
+ /* Skip empty child. */
+ if (IS_DUMMY_REL(child_join))
+ {
+ MemoryContextSwitchTo(old_context);
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ /*
+ * Search for a child path with pathkeys or parameterization
+ * matching that of the given path.
+ */
+ child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
+ best_path->path.pathkeys,
+ PATH_REQ_OUTER(&best_path->path),
+ TOTAL_COST);
+
+ if (!child_path)
+ elog(ERROR, "Could not find a path with required pathkeys.");
+
+ MemoryContextSwitchTo(old_context);
+
+ /* Create plan for the current child. */
+ child_plan = create_plan_recurse(root, child_path, CP_EXACT_TLIST);
+
+ if (pathkeys)
+ {
+ MergeAppend *node = (MergeAppend *) plan;
+
+ Assert(IsA(node, MergeAppend));
+
+ /* Compute sorting info, and adjust subplan's tlist as needed */
+ child_plan = prepare_sort_from_pathkeys(child_plan, pathkeys,
+ child_path->parent->relids,
+ node->sortColIdx,
+ false,
+ &numsortkeys,
+ &sortColIdx,
+ &sortOperators,
+ &collations,
+ &nullsFirst);
+
+ /*
+ * Check that we got the same sort key information. We just Assert
+ * that the sortops match, since those depend only on the pathkeys;
+ * but it seems like a good idea to check the sort column numbers
+ * explicitly, to ensure the tlists really do match up.
+ */
+ Assert(numsortkeys == node->numCols);
+ if (memcmp(sortColIdx, node->sortColIdx,
+ numsortkeys * sizeof(AttrNumber)) != 0)
+ elog(ERROR, "MergeAppend child's targetlist doesn't match MergeAppend");
+ Assert(memcmp(sortOperators, node->sortOperators,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(collations, node->collations,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(nullsFirst, node->nullsFirst,
+ numsortkeys * sizeof(bool)) == 0);
+
+ /* Now, insert a Sort node if subplan isn't sufficiently ordered */
+ if (!pathkeys_contained_in(pathkeys, child_path->pathkeys))
+ {
+ Sort *sort = make_sort(child_plan, numsortkeys,
+ sortColIdx, sortOperators,
+ collations, nullsFirst);
+ label_sort_with_costsize(root, sort, -1.0);
+ child_plan = (Plan *) sort;
+ }
+ }
+
+ child_plans = lappend(child_plans, child_plan);
+
+ /*
+ * Reset the child_join memory context to reclaim the memory consumed
+ * while creating paths.
+ */
+ MemoryContextResetAndDeleteChildren(child_context);
+ }
+
+ /* Destroy the child context as we do not need it anymore. */
+ Assert(CurrentMemoryContext == old_context);
+ MemoryContextDelete(child_context);
+
+ /* Partitioned relation with all empty children gets a dummy path. */
+ Assert(child_plans != NIL);
+
+ if (IsA(plan, MergeAppend))
+ {
+ MergeAppend *node = (MergeAppend *)plan;
+
+ node->mergeplans = child_plans;
+ }
+ else
+ {
+ Append *node = (Append *)plan;
+
+ Assert(IsA(plan, Append));
+ node->appendplans = child_plans;
+ }
+
+ /* Complete rest of the plan. */
+ plan->qual = NIL;
+ plan->lefttree = NULL;
+ plan->righttree = NULL;
+ return plan;
+}
/*****************************************************************************
*
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 6f41979..676204f 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -2179,3 +2179,163 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
/* Now translate for this child */
return adjust_appendrel_attrs(root, node, list_make1(appinfo));
}
+
+/*
+ * build_child_restrictinfo
+ * Returns a RestrictInfo which is derived from the given RestrictInfo by
+ * applying the parent-child translation specified by the list of
+ * AppendRelInfos.
+ *
+ * The topmost parent's RestrictInfo maintains a list of child RestrictInfos
+ * derived from it. If a suitable RestrictInfo is found in that list, it is
+ * returned as is. If there is no such child RestrictInfo, we translate the given
+ * RestrictInfo using the given list of AppendRelInfos and stick it in the
+ * topmost parent's list before returning it to the caller.
+ */
+RestrictInfo *
+build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
+ List *append_rel_infos)
+{
+ Relids child_required_relids;
+ ListCell *lc;
+ RestrictInfo *parent_rinfo;
+ RestrictInfo *child_rinfo;
+ MemoryContext old_context;
+
+ child_required_relids = adjust_relid_set(rinfo->required_relids,
+ append_rel_infos);
+
+
+ /* Nothing to do, if the clause does not need any translation. */
+ if (bms_equal(child_required_relids, rinfo->required_relids))
+ {
+ bms_free(child_required_relids);
+ return rinfo;
+ }
+
+ /*
+ * Check if we already have the RestrictInfo for the given child in the
+ * topmost parent's RestrictInfo.
+ */
+ parent_rinfo = rinfo->parent_rinfo ? rinfo->parent_rinfo : rinfo;
+ foreach (lc, parent_rinfo->child_rinfos)
+ {
+ child_rinfo = lfirst(lc);
+
+ if (bms_equal(child_rinfo->required_relids, child_required_relids))
+ {
+ bms_free(child_required_relids);
+ return child_rinfo;
+ }
+ }
+
+ /*
+ * We didn't find any child restrictinfo for the given child, translate the
+ * given RestrictInfo and stick it into the parent's list. The clause
+ * expression may get used in plan, so create the child RestrictInfo in the
+ * planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ child_rinfo = (RestrictInfo *) adjust_appendrel_attrs(root, (Node *) rinfo,
+ append_rel_infos);
+ bms_free(child_required_relids);
+ parent_rinfo->child_rinfos = lappend(parent_rinfo->child_rinfos,
+ child_rinfo);
+ child_rinfo->parent_rinfo = parent_rinfo;
+
+ MemoryContextSwitchTo(old_context);
+
+ return child_rinfo;
+}
+
+/*
+ * build_child_clauses
+ * Convenience routine to call build_child_restrictinfo on a list of
+ * clauses.
+ */
+List *
+build_child_clauses(PlannerInfo *root, List *clauses, List *append_rel_infos)
+{
+ List *child_clauses = NIL;
+ ListCell *lc;
+
+ foreach (lc, clauses)
+ {
+ RestrictInfo *parent_rinfo = lfirst(lc);
+ RestrictInfo *child_rinfo;
+
+ Assert(IsA(parent_rinfo, RestrictInfo));
+
+ child_rinfo = build_child_restrictinfo(root, parent_rinfo,
+ append_rel_infos);
+
+ child_clauses = lappend(child_clauses, child_rinfo);
+ }
+
+ return child_clauses;
+}
+
+/*
+ * find_appinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *appinfo_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (bms_is_member(appinfo->child_relid, relids))
+ appinfo_list = lappend(appinfo_list, appinfo);
+ }
+
+ Assert(list_length(appinfo_list) == bms_num_members(relids));
+ return appinfo_list;
+}
+
+/*
+ * Construct the SpecialJoinInfo for a child-join by translating
+ * SpecialJoinInfo for the join between parents. left_relids and right_relids
+ * are the relids of left and right side of the join respectively.
+ */
+SpecialJoinInfo *
+build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids)
+{
+ SpecialJoinInfo *sjinfo = makeNode(SpecialJoinInfo);
+ MemoryContext old_context;
+ List *left_appinfos = find_appinfos_by_relids(root, left_relids);
+ List *right_appinfos = find_appinfos_by_relids(root, right_relids);
+
+ memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
+
+ sjinfo->min_lefthand = adjust_relid_set(sjinfo->min_lefthand,
+ left_appinfos);
+ sjinfo->min_righthand = adjust_relid_set(sjinfo->min_righthand,
+ right_appinfos);
+ sjinfo->syn_lefthand = adjust_relid_set(sjinfo->syn_lefthand,
+ left_appinfos);
+ sjinfo->syn_righthand = adjust_relid_set(sjinfo->syn_righthand,
+ right_appinfos);
+
+ /*
+ * Replace the Var nodes of parent with those of children in expressions.
+ * This function may be called within a temporary context, but the
+ * expressions will be shallow-copied into the plan. Hence copy those in
+ * the planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ sjinfo->semi_rhs_exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ right_appinfos);
+ MemoryContextSwitchTo(old_context);
+
+ list_free(left_appinfos);
+ list_free(right_appinfos);
+
+ return sjinfo;
+}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index f440875..d861a49 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -23,7 +23,9 @@
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
@@ -2154,6 +2156,117 @@ create_hashjoin_path(PlannerInfo *root,
}
/*
+ * create_partition_join_path
+ * Creates a pathnode that represents partition-wise join for given
+ * partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the cost of representative child-joins
+ * paths.
+ */
+PartitionJoinPath *
+create_partition_join_path(PlannerInfo *root, RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer, List *pathkeys)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = pathkeys ? T_MergeAppend : T_Append;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = pathkeys;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ if (!pathkeys)
+ {
+ /*
+ * Startup cost of an append relation is the startup cost of the
+ * first subpath. Assume that the given first child will be the
+ * first child in the final plan as well.
+ */
+ if (lc == list_head(subpaths))
+ subpath_startup_cost = subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else if (pathkeys_contained_in(pathkeys, subpath->pathkeys))
+ {
+ /*
+ * Subpath is adequately ordered, we won't need to sort it. We need
+ * all the subplans to return their respective first rows, before
+ * returning a row. So add the startup costs.
+ */
+ subpath_startup_cost += subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else
+ {
+ /* We'll need to insert a Sort node, so include cost for that */
+ Path sort_path; /* dummy for result of cost_sort */
+
+ cost_sort(&sort_path,
+ root,
+ pathkeys,
+ subpath->total_cost,
+ subpath->parent->tuples,
+ subpath->pathtarget->width,
+ 0.0,
+ work_mem,
+ -1);
+ subpath_startup_cost += sort_path.startup_cost;
+ subpath_total_cost += sort_path.total_cost;
+ }
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ if (!pathkeys)
+ pathnode->path.startup_cost = subpath_startup_cost;
+ else
+ pathnode->path.startup_cost = (subpath_startup_cost * pathnode->path.rows) / subpath_rows;
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ /*
+ * Multiply the costs with scaling factor as specified. Used to encourage
+ * or discourage use of partition-wise join plans.
+ */
+ pathnode->path.startup_cost *= partition_wise_plan_weight;
+ pathnode->path.total_cost *= partition_wise_plan_weight;
+
+ return pathnode;
+}
+
+/*
* create_projection_path
* Creates a pathnode that represents performing a projection.
*
diff --git a/src/backend/optimizer/util/placeholder.c b/src/backend/optimizer/util/placeholder.c
index 698a387..e06bccc 100644
--- a/src/backend/optimizer/util/placeholder.c
+++ b/src/backend/optimizer/util/placeholder.c
@@ -20,6 +20,7 @@
#include "optimizer/pathnode.h"
#include "optimizer/placeholder.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/var.h"
#include "utils/lsyscache.h"
@@ -414,6 +415,10 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
Relids relids = joinrel->relids;
ListCell *lc;
+ /* This function is called only on the parent relations. */
+ Assert(!IS_OTHER_REL(joinrel) && !IS_OTHER_REL(outer_rel) &&
+ !IS_OTHER_REL(inner_rel));
+
foreach(lc, root->placeholder_list)
{
PlaceHolderInfo *phinfo = (PlaceHolderInfo *) lfirst(lc);
@@ -459,3 +464,53 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
}
}
}
+
+/*
+ * add_placeholders_to_child_joinrel
+ * Translate the PHVs in parent's targetlist and add them to the child's
+ * targetlist. Also adjust the cost
+ */
+void
+add_placeholders_to_child_joinrel(PlannerInfo *root, RelOptInfo *childrel,
+ RelOptInfo *parentrel)
+{
+ ListCell *lc;
+
+ /* This function is called only for join relations. */
+ Assert(IS_JOIN_REL(childrel) && IS_JOIN_REL(parentrel));
+
+ /* Ensure child relations is really what it claims to be. */
+ Assert(IS_OTHER_REL(childrel));
+
+ foreach (lc, parentrel->reltarget->exprs)
+ {
+ PlaceHolderVar *phv = lfirst(lc);
+
+ if (IsA(phv, PlaceHolderVar))
+ {
+ /*
+ * In case the placeholder Var refers to any of the parent
+ * relations, translate it to refer to the corresponding child.
+ */
+ if (bms_overlap(phv->phrels, parentrel->relids) &&
+ childrel->reloptkind == RELOPT_OTHER_JOINREL)
+ {
+ List *append_rel_infos;
+
+ append_rel_infos = find_appinfos_by_relids(root,
+ childrel->relids);
+ phv = (PlaceHolderVar *) adjust_appendrel_attrs(root,
+ (Node *) phv,
+ append_rel_infos);
+ }
+
+ childrel->reltarget->exprs = lappend(childrel->reltarget->exprs,
+ phv);
+ }
+ }
+
+ /* Adjust the cost and width of child targetlist. */
+ childrel->reltarget->cost.startup = parentrel->reltarget->cost.startup;
+ childrel->reltarget->cost.per_tuple = parentrel->reltarget->cost.per_tuple;
+ childrel->reltarget->width = parentrel->reltarget->width;
+}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 19982dc..1eed987 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -23,6 +23,7 @@
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
#include "utils/hsearch.h"
@@ -54,6 +55,9 @@ static void set_foreign_rel_properties(RelOptInfo *joinrel,
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
Relids required_outer);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
/*
@@ -434,6 +438,9 @@ build_join_rel(PlannerInfo *root,
RelOptInfo *joinrel;
List *restrictlist;
+ /* This function should be used only for join between parents. */
+ Assert(!IS_OTHER_REL(outer_rel) && !IS_OTHER_REL(inner_rel));
+
/*
* See if we already have a joinrel for this set of base rels.
*/
@@ -532,6 +539,10 @@ build_join_rel(PlannerInfo *root,
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
@@ -594,6 +605,126 @@ build_join_rel(PlannerInfo *root,
return joinrel;
}
+ /*
+ * build_child_join_rel
+ * Builds RelOptInfo for joining given two child relations from RelOptInfo
+ * representing the join between their parents.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of child relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for child join
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_appinfos': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ JoinType jointype)
+{
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel) && IS_OTHER_REL(inner_rel));
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Compute information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /* Build targetlist */
+ build_joinrel_tlist(root, joinrel, outer_rel);
+ build_joinrel_tlist(root, joinrel, inner_rel);
+ /* Add placeholder variables. */
+ add_placeholders_to_child_joinrel(root, joinrel, parent_joinrel);
+
+ /* Construct joininfo list. */
+ joinrel->joininfo = build_child_clauses(root, parent_joinrel->joininfo,
+ find_appinfos_by_relids(root,
+ joinrel->relids));
+
+ /*
+ * Lateral relids referred in child join will be same as that referred in
+ * the parent relation. Throw any partial result computed while building
+ * the targetlist.
+ */
+ bms_free(joinrel->direct_lateral_relids);
+ bms_free(joinrel->lateral_relids);
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, jointype);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ /* We build the join only once. */
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
/*
* min_join_parameterization
*
@@ -649,9 +780,15 @@ static void
build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *vars;
+ /* attrs_needed refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(vars, input_rel->reltarget->exprs)
{
Var *var = (Var *) lfirst(vars);
@@ -667,23 +804,47 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
/*
* Otherwise, anything in a baserel or joinrel targetlist ought to be
- * a Var. (More general cases can only appear in appendrel child
- * rels, which will never be seen here.)
+ * a Var or ConvertRowtypeExpr introduced while translating parent
+ * targetlist to that of the child.
*/
- if (!IsA(var, Var))
+ if (IsA(var, Var))
+ {
+ /* Get the Var's original base rel */
+ baserel = find_base_rel(root, var->varno);
+
+ /* Is it still needed above this joinrel? */
+ ndx = var->varattno - baserel->min_attr;
+ }
+ else if (IsA(var, ConvertRowtypeExpr))
+ {
+ ConvertRowtypeExpr *child_expr = (ConvertRowtypeExpr *) var;
+ Var *childvar = (Var *) child_expr->arg;
+
+ /*
+ * Child's whole-row references are converted to that of parent
+ * using ConvertRowtypeExpr. In this case, the argument to
+ * ConvertRowtypeExpr is expected to be a whole-row reference of
+ * the child.
+ */
+ Assert(IsA(childvar, Var) && childvar->varattno == 0);
+
+ baserel = find_base_rel(root, childvar->varno);
+ ndx = 0 - baserel->min_attr;
+ }
+ else
elog(ERROR, "unexpected node type in rel targetlist: %d",
(int) nodeTag(var));
- /* Get the Var's original base rel */
- baserel = find_base_rel(root, var->varno);
-
- /* Is it still needed above this joinrel? */
- ndx = var->varattno - baserel->min_attr;
if (bms_nonempty_difference(baserel->attr_needed[ndx], relids))
{
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs, var);
- /* Vars have cost zero, so no need to adjust reltarget->cost */
+
+ /*
+ * Vars have cost zero, so no need to adjust reltarget->cost. Even
+ * if, it's a ConvertRowtypeExpr, it will be computed only for the
+ * base relation, costing nothing for a join.
+ */
joinrel->reltarget->width += baserel->attr_widths[ndx];
}
}
@@ -820,6 +981,9 @@ subbuild_joinrel_joinlist(RelOptInfo *joinrel,
{
ListCell *l;
+ /* Expected to be called only for join between parent relations. */
+ Assert(joinrel->reloptkind == RELOPT_JOINREL);
+
foreach(l, joininfo_list)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(l);
@@ -1366,3 +1530,85 @@ find_param_path_info(RelOptInfo *rel, Relids required_outer)
return NULL;
}
+
+/*
+ * build_joinrel_partition_info
+ * If the join between given partitioned relations is possibly partitioned
+ * set the partitioning scheme and partition keys expressions for the
+ * join.
+ *
+ * If the two relations have same partitioning scheme, their join may be
+ * partitioned and will follow the same partitioning scheme as the joining
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /* Nothing to do if partition-wise join technique is disabled. */
+ if (!enable_partition_wise_join)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * The join is not partitioned, if any of the relations being joined are
+ * not partitioned or they do not have same partitioning scheme.
+ */
+ if (!outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel, hence it should
+ * not have partition scheme, partition key expressions and array for
+ * storing child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ /*
+ * Join relation is partitioned using same partitioning scheme as the
+ * joining relations.
+ */
+ joinrel->part_scheme = outer_rel->part_scheme;
+ num_pks = joinrel->part_scheme->partnatts;
+
+ /*
+ * Construct partition keys for the join.
+ *
+ * An INNER join between two partitioned relations is partition by key
+ * expressions from both the relations. For tables A and B partitioned by a and b
+ * respectively, (A INNER JOIN B ON A.a = B.b) is partitioned by both A.a
+ * and B.b.
+ *
+ * An OUTER join like (A LEFT JOIN B ON A.a = B.b) may produce rows with
+ * B.b NULL. These rows may not fit the partitioning conditions imposed on
+ * B.b. Hence, strictly speaking, the join is not partitioned by B.b.
+ * Strictly speaking, partition keys of an OUTER join should include
+ * partition key expressions from the OUTER side only. Consider a join like
+ * (A LEFT JOIN B on (A.a = B.b) LEFT JOIN C ON B.b = C.c. If we do not
+ * include B.b as partition key expression for (AB), it prohibits us from
+ * using partition-wise join when joining (AB) with C as there is no
+ * equi-join between partition keys of joining relations. But two NULL
+ * values are never equal and no two rows from mis-matching partitions can
+ * join. Hence it's safe to include B.b as partition key expression for
+ * (AB), even though rows in (AB) are not strictly partitioned by B.b.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index de85eca..afd0c23 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -901,6 +901,15 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
@@ -2947,6 +2956,25 @@ static struct config_real ConfigureNamesReal[] =
},
{
+ {"partition_wise_plan_weight", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Multiplication factor for partition-wise plan costs."),
+ NULL
+ },
+ &partition_wise_plan_weight,
+ DEFAULT_PARTITION_WISE_PLAN_WEIGHT, 0, DBL_MAX,
+ NULL, NULL, NULL
+ },
+ {
+ {"sample_partition_fraction", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Fraction of partitions to be used as sample for calculating total cost of partition-wise plans."),
+ NULL
+ },
+ &sample_partition_fraction,
+ DEFAULT_SAMPLE_PARTITION_FRACTION, 0, 1,
+ NULL, NULL, NULL
+ },
+
+ {
{"bgwriter_lru_multiplier", PGC_SIGHUP, RESOURCES_BGWRITER,
gettext_noop("Multiple of the average buffer usage to free per round."),
NULL
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 95dd8ba..292d9a6 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -240,6 +240,7 @@ typedef enum NodeTag
T_NestPath,
T_MergePath,
T_HashPath,
+ T_PartitionJoinPath,
T_AppendPath,
T_MergeAppendPath,
T_ResultPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 4f99184..146d53b 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -391,6 +391,11 @@ typedef struct PartitionSchemeData *PartitionScheme;
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing joins between child relations of
+ * different partitioned tables. These relations are not added to
+ * join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
@@ -512,10 +517,19 @@ typedef enum RelOptKind
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(rel) \
+ ((rel)->reloptkind == RELOPT_OTHER_MEMBER_REL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
+#define IS_JOIN_REL(rel) \
+ ((rel)->reloptkind == RELOPT_JOINREL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
@@ -600,6 +614,14 @@ typedef struct RelOptInfo
* as the number of joining
* relations.
*/
+
+ /* For joins between partitioned tables. */
+ List *partitioned_joins; /* List of join orders which yield
+ * relations partitioned by above
+ * partition scheme.
+ */
+ /* Set only for "other" base or "other" join relations. */
+ Relids top_parent_relids; /* Relids of topmost parents. */
} RelOptInfo;
/*
@@ -1540,6 +1562,14 @@ typedef struct LimitPath
Node *limitCount; /* COUNT parameter, or NULL if none */
} LimitPath;
+/*
+ * PartitionJoinPath represents partition-wise join between two partitioned
+ * tables.
+ */
+typedef struct PartitionJoinPath
+{
+ Path path;
+} PartitionJoinPath;
/*
* Restriction clause info.
@@ -1747,6 +1777,18 @@ typedef struct RestrictInfo
/* cache space for hashclause processing; -1 if not yet set */
Selectivity left_bucketsize; /* avg bucketsize of left side */
Selectivity right_bucketsize; /* avg bucketsize of right side */
+
+ /*
+ * Repository to locate child RestrictInfos derived from parent
+ * RestrictInfo. Every derived child RestrictInfo points to the parent
+ * RestrictInfo from which it is derived. Parent RestrictInfo maintains a
+ * list of all derived child RestrictInfos. So only one of the following
+ * should be set.
+ */
+ List *child_rinfos; /* RestrictInfos derived for children. */
+ struct RestrictInfo *parent_rinfo; /* Parent restrictinfo this
+ * RestrictInf is derived from.
+ */
} RestrictInfo;
/*
@@ -1869,6 +1911,21 @@ typedef struct SpecialJoinInfo
} SpecialJoinInfo;
/*
+ * Partitioned join information
+ *
+ * Saves information about relations which can be joined partition-wise and
+ * thus produce result which is partitioned by the partition scheme of the
+ * relation.
+ */
+typedef struct PartitionedJoin
+{
+ RelOptInfo *rel1;
+ RelOptInfo *rel2;
+ SpecialJoinInfo *sjinfo; /* SpecialJoinInfo applicable. */
+ List *restrictlist; /* applicable join clauses. */
+} PartitionedJoin;
+
+/*
* Append-relation info.
*
* When we expand an inheritable table or a UNION-ALL subselect into an
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 0e68264..a13eff1 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -30,6 +30,8 @@
#define DEFAULT_PARALLEL_SETUP_COST 1000.0
#define DEFAULT_EFFECTIVE_CACHE_SIZE 524288 /* measured in pages */
+#define DEFAULT_PARTITION_WISE_PLAN_WEIGHT 1
+#define DEFAULT_SAMPLE_PARTITION_FRACTION 0.01
typedef enum
{
@@ -66,7 +68,10 @@ extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
+extern double partition_wise_plan_weight;
+extern double sample_partition_fraction;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 7b41317..81d637a 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -229,6 +229,9 @@ extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
+extern PartitionJoinPath *create_partition_join_path(PlannerInfo *root,
+ RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer, List *pathkeys);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
@@ -271,5 +274,8 @@ extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, JoinType jointype);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 81a9be7..7ad19be 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -53,6 +53,8 @@ extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
extern void generate_gather_paths(PlannerInfo *root, RelOptInfo *rel);
+extern void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
#ifdef OPTIMIZER_DEBUG
extern void debug_print_rel(PlannerInfo *root, RelOptInfo *rel);
@@ -106,6 +108,9 @@ extern bool have_join_order_restriction(PlannerInfo *root,
RelOptInfo *rel1, RelOptInfo *rel2);
extern bool have_dangerous_phv(PlannerInfo *root,
Relids outer_relids, Relids inner_params);
+extern void add_paths_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *parent_joinrel,
+ int child_id);
/*
* equivclass.c
diff --git a/src/include/optimizer/placeholder.h b/src/include/optimizer/placeholder.h
index 11e6403..8598268 100644
--- a/src/include/optimizer/placeholder.h
+++ b/src/include/optimizer/placeholder.h
@@ -28,5 +28,7 @@ extern void fix_placeholder_input_needed_levels(PlannerInfo *root);
extern void add_placeholders_to_base_rels(PlannerInfo *root);
extern void add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+extern void add_placeholders_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *childrel, RelOptInfo *parentrel);
#endif /* PLACEHOLDER_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index a02e06a..5832130 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -57,5 +57,13 @@ extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
+extern RestrictInfo *build_child_restrictinfo(PlannerInfo *root,
+ RestrictInfo *rinfo, List *append_rel_infos);
+extern List *build_child_clauses(PlannerInfo *root, List *clauses,
+ List *append_rel_infos);
+extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
+extern SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids);
#endif /* PREP_H */
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
index 18238fa..79779d6 100644
--- a/src/test/regress/expected/partition_join.out
+++ b/src/test/regress/expected/partition_join.out
@@ -2,6 +2,10 @@
-- PARTITION_JOIN
-- Test partition-wise join between partitioned tables
--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
--
-- partitioned by a single column
--
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index d48abd7..c6c1405 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -70,20 +70,21 @@ select count(*) >= 0 as ok from pg_prepared_xacts;
-- This is to record the prevailing planner enable_foo settings during
-- a regression test run.
select name, setting from pg_settings where name like 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
-- Test that the pg_timezone_names and pg_timezone_abbrevs views are
-- more-or-less working. We can't test their contents in any great detail
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
index 0322f1e..9b2baeb 100644
--- a/src/test/regress/sql/partition_join.sql
+++ b/src/test/regress/sql/partition_join.sql
@@ -3,6 +3,11 @@
-- Test partition-wise join between partitioned tables
--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
+
--
-- partitioned by a single column
--
--
1.7.9.5
0009-Adjust-join-related-to-code-to-accept-child-relation.patchapplication/octet-stream; name=0009-Adjust-join-related-to-code-to-accept-child-relation.patchDownload
From e8fb61d8be1596b7c9727b29869cecdeb932ee1f Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 17:16:46 +0530
Subject: [PATCH 09/11] Adjust join related to code to accept child relations.
Existing join related code doesn't expect child relations to be joined. This
patch contains various fixes to change that.
1. Uniqe-ifying joining relations.
=================================
For semi-joins we unique-ify the joining relations, which tries to estimate
nummber of unique values using estimate_num_groups(). This function doesn't
expect a Var from a child relation and contained an assertion to that effect.
With partition-wise joins, we may compute a join between child relations. This
commit changes that assertion to include child relation. The function doesn't
need any change other than that to accomodate child relations.
2. OUTER joins require dummy child relations to have targetlist.
================================================================
We need a targetlist defining nullable columns for an outer join, even if the
relation on the nullable side is deemed to be empty. Prior to partition-wise
join an empty child relation never had a targetlist since it was eliminated
from planning. But with partition-wise join an empty child relation may
participate in an outer join with another non-empty child relation. Hence set
targetlist for a child relation even if it's dummy.
3. prepare_sort_from_pathkeys fixes.
====================================
Before partition-wise join feature were never required to be directly sorted,
let's say for merge joins. With partition-wise join feature, the child
relations will participate directly in the join and also need to be sorted
directly for the purpose of merge join. In order to sort a relation, we use
pathkeys. The expression on which to sort a particular relation is provided by
the equivalence member corresponding to that relation in the equivalence class
referred by the pathkeys. Since the code doesn't expect child relations to
bubble up to the sorting, the function prepare_sort_from_pathkeys() skips any
child members (those set with em_is_child) unless the caller specifically asks
for child relations by passing relids. make_sort_from_pathkeys() calls
prepare_sort_from_pathkeys() to create Sort plan for outer and inner plans
without passing relids of the relation to be sorted. For partition-wise joins
the outer and inner plans produce child relations and thus
prepare_sort_from_pathkeys() does not find equivalence members since it skips
child members for the want of relids. This particular instance can be fixed by
passing outer/inner_path->parent->relids to prepare_sort_from_pathkeys().
All the callers of prepare_sort_from_pathkeys() viz.
create_merge_append_plan(), create_merge_append_plan(),
create_windowagg_plan() except make_sort_from_pathkeys() pass relids to
prepare_sort_from_pathkeys(). make_sort_from_pathkeys() as well passes those
with this patch.
make_sort_from_pathkeys() itself doesn't know the relids of relation being
sorted. It just gets the plan. Hence we need to pass relids to
make_sort_from_pathkeys() and thus change each of its callers to pass relids,
if required.
It has two callers as of now.
1. create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags): does
not handle child relations yet, so doesn't need any change.
2. create_mergejoin_plan(PlannerInfo *root, MergePath *best_path):
It requires this change and the relids can be obtained from the outer and inner
path's parent RelOptInfo.
4. Handling em_is_child cases.
==============================
Right now, when comparing relids for child relations, only exact match is
considered. This is fine as long as em_relids has only a single member in it
and the passed in relids has only a single member in it. But with
partition-wise join, relids can have multiple members and em_relids may not
exactly match the given relids. But we need to find the member which covers
subset of given relids.
---
src/backend/optimizer/path/allpaths.c | 41 +++++++++++++++++--------------
src/backend/optimizer/plan/createplan.c | 28 +++++++++++++--------
src/backend/utils/adt/selfuncs.c | 3 ++-
3 files changed, 42 insertions(+), 30 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 1adf6ba..b4cd5ab 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -960,11 +960,27 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
- * We have to copy the parent's targetlist and quals to the child,
- * with appropriate substitution of variables. However, only the
- * baserestrictinfo quals are needed before we can check for
- * constraint exclusion; so do that first and then check to see if we
- * can disregard this child.
+ * Copy/Modify targetlist. Even if this child is deemed empty, we need
+ * its targetlist in case it falls on nullable side in a child-join
+ * because of partition-wise join.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ appinfo_list);
+
+ /*
+ * We have to copy the parent's quals to the child, with appropriate
+ * substitution of variables. However, only the baserestrictinfo quals
+ * are needed before we can check for constraint exclusion; so do that
+ * first and then check to see if we can disregard this child.
*
* The child rel's targetlist might contain non-Var expressions, which
* means that substitution into the quals could produce opportunities
@@ -1091,22 +1107,9 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying targetlist and join quals. */
childrel->joininfo = build_child_clauses(root, rel->joininfo,
appinfo_list);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo_list);
/*
* We have to make child entries in the EquivalenceClass data
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index fe6b7f8..d0705dc 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -245,7 +245,8 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
@@ -1555,7 +1556,7 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
@@ -3572,6 +3573,8 @@ create_mergejoin_plan(PlannerInfo *root,
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
@@ -3635,8 +3638,10 @@ create_mergejoin_plan(PlannerInfo *root,
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
@@ -3647,8 +3652,10 @@ create_mergejoin_plan(PlannerInfo *root,
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
@@ -5630,11 +5637,11 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
@@ -5745,10 +5752,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
@@ -5769,9 +5776,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
@@ -5781,7 +5789,7 @@ make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index fa32e9e..c833846 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3427,7 +3427,8 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
if (rel->tuples > 0)
{
/*
--
1.7.9.5
0010-Parameterized-path-fixes.patchapplication/octet-stream; name=0010-Parameterized-path-fixes.patchDownload
From 406fdb63f146b2baca9afaa78735ddc121ec9671 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 17:25:25 +0530
Subject: [PATCH 10/11] Parameterized path fixes.
We do not create merge or hash join paths when the inner path is parameterized
by the outer and vice-versa. Parameterization information in path refers to the
top-most parent relation. Current tests (PATH_PARAM_BY_REL) to avoid joining
such paths fail while joining child relations; the paths from either child may
be paramterized by other's parent. Modify the tests to consider paths
parameterized by parent as parameterized by any of its child.
If the inner path is parameterized by outer path, we can create a nested loop
join using those two paths with inner relation parameterized by the outer
relation. For LATERAL JOINs this is the only legal way to plan a join. In case
of partitioned joins, the lateral references refer to the topmost parent and
hence inner paths are parameterized by the topmost parent. In such cases, it's
possible to translate the inner path to be parameterized by
the child and create nested loop join. When presented with a pair of child
relation paths, where the inner paths is parameterized by the parent of outer
child, this patch translates the path to be parameterized by the outer child
and creates a nested loop join path.
The function reparameterize_path_by_child() needs to call adjust_relid_set() to
substitute parent relids by child relids in Path::param_info::ppi_req_outer.
Hence "extern"alized that function. Since there is already another
static adjust_relid_set() in rewriteManip.c, renamed this one to
adjust_child_relids().
Also "extern"alized find_param_path_info() required by
reparameterize_path_by_child().
---
src/backend/optimizer/path/joinpath.c | 33 +++++-
src/backend/optimizer/prep/prepunion.c | 42 ++++----
src/backend/optimizer/util/pathnode.c | 180 ++++++++++++++++++++++++++++++++
src/backend/optimizer/util/relnode.c | 2 -
src/include/optimizer/pathnode.h | 4 +
src/include/optimizer/prep.h | 1 +
6 files changed, 237 insertions(+), 25 deletions(-)
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index f80fb25..4d4a183 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -25,9 +25,19 @@
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+/*
+ * Paths parameterized by the parent can be considered to be parameterized by
+ * any of its child.
+ */
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
@@ -301,6 +311,27 @@ try_nestloop_path(PlannerInfo *root,
JoinCostWorkspace workspace;
/*
+ * Since result produced by a child is part of the result produced by its
+ * topmost parent and has same properties, the parameters representing that
+ * parent may be substituted by values from a child. Hence expressions and
+ * hence paths using those expressions, parameterized by a parent can be
+ * said to be parameterized by any of its child. For a join between child
+ * relations, if the inner path is parameterized by the parent of the outer
+ * relation, create a nestloop join path with inner relation parameterized
+ * by the outer relation by translating the inner path to be parameterized
+ * by the outer child relation.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_by_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 676204f..d459e95 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -109,7 +109,6 @@ static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
-static Relids adjust_relid_set(Relids relids, List *append_rel_infos);
/*
@@ -1951,7 +1950,7 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == 0)
- phv->phrels = adjust_relid_set(phv->phrels, context->appinfos);
+ phv->phrels = adjust_child_relids(phv->phrels, context->appinfos);
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1982,17 +1981,17 @@ adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_mutator((Node *) oldinfo->orclause, context);
/* adjust relid sets too */
- newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
+ newinfo->clause_relids = adjust_child_relids(oldinfo->clause_relids,
context->appinfos);
- newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
+ newinfo->required_relids = adjust_child_relids(oldinfo->required_relids,
context->appinfos);
- newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
+ newinfo->outer_relids = adjust_child_relids(oldinfo->outer_relids,
context->appinfos);
- newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
+ newinfo->nullable_relids = adjust_child_relids(oldinfo->nullable_relids,
context->appinfos);
- newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
+ newinfo->left_relids = adjust_child_relids(oldinfo->left_relids,
context->appinfos);
- newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
+ newinfo->right_relids = adjust_child_relids(oldinfo->right_relids,
context->appinfos);
/*
@@ -2026,15 +2025,18 @@ adjust_appendrel_attrs_mutator(Node *node,
/*
* Replace parent relids by child relids in the copy of given relid set
- * according to the given list of AppendRelInfos. The given relid set is
- * returned as is if it contains no parent in the given list, otherwise, the
- * given relid set is not changed.
+ * according to the given list of AppendRelInfos.
*/
Relids
-adjust_relid_set(Relids relids, List *append_rel_infos)
+adjust_child_relids(Relids relids, List *append_rel_infos)
{
ListCell *lc;
- Bitmapset *result = NULL;
+
+ /*
+ * The new relids set may be expected to be in a memory context different
+ * from the given one. Make a copy here.
+ */
+ Bitmapset *result = bms_copy(relids);
foreach (lc, append_rel_infos)
{
@@ -2043,10 +2045,6 @@ adjust_relid_set(Relids relids, List *append_rel_infos)
/* Remove parent, add child */
if (bms_is_member(appinfo->parent_relid, relids))
{
- /* Make a copy if we are changing the set. */
- if (!result)
- result = bms_copy(relids);
-
result = bms_del_member(result, appinfo->parent_relid);
result = bms_add_member(result, appinfo->child_relid);
}
@@ -2202,7 +2200,7 @@ build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
RestrictInfo *child_rinfo;
MemoryContext old_context;
- child_required_relids = adjust_relid_set(rinfo->required_relids,
+ child_required_relids = adjust_child_relids(rinfo->required_relids,
append_rel_infos);
@@ -2313,13 +2311,13 @@ build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
- sjinfo->min_lefthand = adjust_relid_set(sjinfo->min_lefthand,
+ sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
left_appinfos);
- sjinfo->min_righthand = adjust_relid_set(sjinfo->min_righthand,
+ sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
right_appinfos);
- sjinfo->syn_lefthand = adjust_relid_set(sjinfo->syn_lefthand,
+ sjinfo->syn_lefthand = adjust_child_relids(sjinfo->syn_lefthand,
left_appinfos);
- sjinfo->syn_righthand = adjust_relid_set(sjinfo->syn_righthand,
+ sjinfo->syn_righthand = adjust_child_relids(sjinfo->syn_righthand,
right_appinfos);
/*
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index d861a49..f322320 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -3388,3 +3388,183 @@ reparameterize_path(PlannerInfo *root, Path *path,
}
return NULL;
}
+
+/*
+ * reparameterize_path_by_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ *
+ * The cost, number of rows, width and parallel path properties depend upon
+ * path->parent, which does not change during the translation. Hence those
+ * members are copied as they are.
+ */
+
+Path *
+reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+ Relids required_outer;
+
+ /*
+ * If the path is not parameterized by parent of the given relation or it it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ required_outer = adjust_child_relids(old_ppi->ppi_req_outer, child_aris);
+
+ /* If we already have a PPI for this parameterization, just return it */
+ new_ppi = find_param_path_info(new_path->parent, required_outer);
+
+ /* If not build a new one and link it to the list of PPIs. */
+ if (!new_ppi)
+ {
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = required_outer;
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = build_child_clauses(root, old_ppi->ppi_clauses,
+ child_aris);
+ new_path->parent->ppilist = lappend(new_path->parent->ppilist, new_ppi);
+ }
+ else
+ bms_free(required_outer);
+
+ new_path->param_info = new_ppi;
+
+ /*
+ * Adjust the path target if the parent of the outer relation is referenced
+ * in the targetlist. This can happen when only the parent of outer relation is
+ * laterally referenced in this relation.
+ */
+ if (bms_overlap(path->parent->lateral_relids, child_rel->top_parent_relids))
+ {
+ MemoryContext old_context;
+
+ /*
+ * Allocate the target in planner's context, since they are copies as
+ * is from path while creating plans.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ MemoryContextSwitchTo(old_context);
+ }
+
+ /*
+ * Change parameterization of subpaths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_by_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_by_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = build_child_clauses(root,
+ jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_by_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexclauses = build_child_clauses(root, ipath->indexclauses,
+ child_aris);
+ ipath->indexquals = build_child_clauses(root, ipath->indexquals,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 1eed987..46eea02 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -53,8 +53,6 @@ static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
static void set_foreign_rel_properties(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
-extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
- Relids required_outer);
static void build_joinrel_partition_info(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel,
JoinType jointype);
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 81d637a..b9f5b11 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -236,6 +236,8 @@ extern PartitionJoinPath *create_partition_join_path(PlannerInfo *root,
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
@@ -277,5 +279,7 @@ extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
RelOptInfo *outer_rel, RelOptInfo *inner_rel,
RelOptInfo *parent_joinrel, JoinType jointype);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index 5832130..0347b37 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -65,5 +65,6 @@ extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
extern SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
SpecialJoinInfo *parent_sjinfo,
Relids left_relids, Relids right_relids);
+extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
#endif /* PREP_H */
--
1.7.9.5
0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patchapplication/octet-stream; name=0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patchDownload
From 38c9b261a37a402c980b0b64427a4f76ea44f345 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 8 Feb 2017 14:42:15 +0530
Subject: [PATCH 11/11] Use IS_JOIN_REL() instead of RELOPT_JOINREL
FDW code uses RELOPT_JOINREL to check whether a given relation is a join or
not. Partition-wise joins create child-join relations, which are marked as
RELOPT_OTHER_JOINREL. Macro IS_JOIN_REL() returns true for both of those kinds,
replace RELOPT_JOINREL tests with IS_JOIN_REL() test.
Similarly replace RELOPT_OTHER_MEMBER_REL test with IS_OTHER_REL() where we
want to test for child relations of all kinds.
---
contrib/postgres_fdw/deparse.c | 10 +++++-----
contrib/postgres_fdw/postgres_fdw.c | 10 ++++++----
src/backend/foreign/foreign.c | 6 +++---
3 files changed, 14 insertions(+), 12 deletions(-)
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index d2b94aa..a2171d7 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -911,7 +911,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
* We handle relations for foreign tables, joins between those and upper
* relations.
*/
- Assert(rel->reloptkind == RELOPT_JOINREL ||
+ Assert(IS_JOIN_REL(rel) ||
rel->reloptkind == RELOPT_BASEREL ||
rel->reloptkind == RELOPT_OTHER_MEMBER_REL ||
rel->reloptkind == RELOPT_UPPER_REL);
@@ -990,7 +990,7 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
@@ -1030,7 +1030,7 @@ deparseFromExpr(List *quals, deparse_expr_cxt *context)
/* For upper relations, scanrel must be either a joinrel or a baserel */
Assert(context->foreignrel->reloptkind != RELOPT_UPPER_REL ||
- scanrel->reloptkind == RELOPT_JOINREL ||
+ IS_JOIN_REL(scanrel) ||
scanrel->reloptkind == RELOPT_BASEREL);
/* Construct FROM clause */
@@ -1178,7 +1178,7 @@ deparseLockingClause(deparse_expr_cxt *context)
appendStringInfoString(buf, " FOR UPDATE");
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(rel))
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
else
@@ -1342,7 +1342,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
RelOptInfo *rel_o = fpinfo->outerrel;
RelOptInfo *rel_i = fpinfo->innerrel;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index 5d270b9..2487f26 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -723,6 +723,8 @@ get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel)
/* If this is a child rel, we must use the topmost parent rel to search. */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->top_parent_relids;
else
relids = rel->relids;
@@ -1181,7 +1183,7 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
@@ -1247,7 +1249,7 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2527,7 +2529,7 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
@@ -2609,7 +2611,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind == RELOPT_JOINREL)
+ else if (IS_JOIN_REL(foreignrel))
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index fdb4f71..e8ca7df 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -717,7 +717,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
{
ListCell *lc;
- Assert(joinrel->reloptkind == RELOPT_JOINREL);
+ Assert(IS_JOIN_REL(joinrel));
foreach(lc, joinrel->pathlist)
{
@@ -782,7 +782,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->outerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->outerjoinpath = foreign_path->fdw_outerpath;
}
@@ -791,7 +791,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->innerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->innerjoinpath = foreign_path->fdw_outerpath;
}
--
1.7.9.5
Fixed a problem with the way qsort was being used in the earlier set
of patches. Attached PFA the set of patches with that fixed.
On Thu, Feb 9, 2017 at 4:20 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
Per your suggestion I have split the patch into many smaller patches.
0001-Refactor-set_append_rel_pathlist.patch
0002-Refactor-make_join_rel.patch
0003-Refactor-adjust_appendrel_attrs.patch
0004-Refactor-build_join_rel.patch
0005-Add-function-find_param_path_info.patchThese four refactor existing code.
0006-Canonical-partition-scheme.patch
0007-Partition-wise-join-tests.patch -- just tests, they fail
0008-Partition-wise-join.patch -- actual patch implementing
partition-wise join, still some tests fail\0009-Adjust-join-related-to-code-to-accept-child-relation.patch
0010-Parameterized-path-fixes.patch
0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patchThe last three patches change existing code to expect child(-join)
relations where they were not expected earlier.Each patch has summary of the changes.
Partition-wise join for multi-level partitioned tables is not covered
by these patches. I will post those patches soon.Other questions/comments:
Why does find_partition_scheme need to copy the partition bound
information instead of just pointing to it? Amit went to some trouble
to make sure that this can't change under us while we hold a lock on
the relation, and we'd better hold a lock on the relation if we're
planning a query against it.PartitionScheme is shared across multiple relations, join or base,
partitioned similarly. Obviously it can't and does not need to point
partition bound informations (which should all be same) of all those
base relations. O the the face of it, it looks weird that it points to
only one of them, mostly the one which it encounters first. But, since
it's going to be the same partition bound information, it doesn't
matter which one. So, I think, we can point of any one of those. Do
you agree?Instead of copying PartitionBoundInfo, used pointer of the first
encountered one.I think the PartitionScheme stuff should live in the optimizer rather
that src/backend/catalog/partition.c. Maybe plancat.c? Perhaps we
eventually need a new file in the optimizer just for partitioning
stuff, but I'm not sure about that yet.I placed PartitionScheme stuff in partition.c because most of the
functions and structures in partition.c are not visible outside that
file. But I will try again to locate PartitionScheme to optimizer.Moved the code as per your suggestion.
The fact that set_append_rel_size needs to reopen the relation to
extract a few more bits of information is not desirable. You need to
fish this information through in some other way; for example, you
could have get_relation_info() stash the needed bits in the
RelOptInfo.I considered this option and discarded it, since not all partitioned
relations will have OIDs for partitions e.g. partitioned joins will
not have OIDs for their partitions. But now that I think of it, we
should probably store those OIDs just for the base relation and leave
them unused for non-base relations just like other base relation
specific fields in RelOptInfo.Changed as per your suggestions.
+ * For two partitioned tables with the same partitioning scheme, it is + * assumed that the Oids of matching partitions from both the tables + * are placed at the same position in the array of partition oids inRather than saying that we assume this, you should say why it has to
be true. (If it doesn't have to be true, we shouldn't assume it.)Will take care of this.
Done. Please check.
+ * join relations. Partition tables should have same layout as the + * parent table and hence should not need any translation. But rest ofThe same attributes have to be present with the same types, but they
can be rearranged. This comment seems to imply the contrary.Hmm, will take care of this.
Done.
FRACTION_PARTS_TO_PLAN seems like it should be a GUC.
+1. Will take care of this. Does "representative_partitions_fraction"
or "sample_partition_fraction" look like a good GUC name? Any other
suggestions?used "sample_partition_fraction" for now. Suggestions are welcome.
+ /* + * Add this relation to the list of samples ordered by the increasing + * number of rows at appropriate place. + */ + foreach (lc, ordered_child_nos) + { + int child_no = lfirst_int(lc); + RelOptInfo *other_childrel = rel->part_rels[child_no]; + + /* + * Keep track of child with lowest number of rows but higher than the + * that of the child being inserted. Insert the child before a + * child with highest number of rows lesser than it. + */ + if (child_rel->rows <= other_childrel->rows) + insert_after = lc; + else + break; + }Can we use quicksort instead of a hand-coded insertion sort?
I guess so, if I write comparison functions, which shouldn't be a
problem. Will try that.Done.
+ if (bms_num_members(outer_relids) > 1)
Seems like bms_get_singleton_member could be used.
That code is not required any more.
+ * Partitioning scheme in join relation indicates a possibilty that the
Spelling.
Done.
There seems to be no reason for create_partition_plan to be separated
from create_plan_recurse. You can just add another case for the new
path type.Done.
Why does create_partition_join_path need to be separate from
create_partition_join_path_with_pathkeys? Couldn't that be combined
into a single function with a pathkeys argument that might sometimes
be NIL? I assume most of the logic is common.Combined those into a single function.
From a sort of theoretical standpoint, the biggest danger of this
patch seems to be that by deferring path creation until a later stage
than normal, we could miss some important processing.
subquery_planner() does a lot of stuff after
expand_inherited_tables(); if any of those things, especially the ones
that happen AFTER path generation, have an effect on the paths, then
this code needs to compensate for those changes somehow. It seems
like having the planning of unsampled children get deferred until
create_plan() time is awfully surprising; here we are creating the
plan and suddenly what used to be a straightforward path->plan
translation is running around doing major planning work. I can't
entirely justify it, but I somehow have a feeling that work ought to
be moved earlier. Not sure exactly where.Pasting my previous replies here to keep everything in one mail.
I agree with this. Probably we should add a path tree mutator before
SS_identify_outer_params() to replace any Partition*Paths with
Merge/Append paths. The mutator will create paths for child-joins
within temporary memory context, copy the relevant paths and create
Merge/Append paths. There are two problems there 1. We have to write
code to copy paths; most of the paths would be flat copy but custom
scan paths might have some unexpected problems. 2. There will be many
surviving PartitionPaths, and all the corresponding child paths would
need copying and consume memory. In order to reduce that consumption,
we have run this mutator after set_cheapest() in subquery_planner();
but then nothing interesting happens between that and create_plan().
Expanding PartitionPaths during create_plan() does not need any path
copying and we expand only the PartitionPaths which will be converted
to plans. That does save a lot of memory; the reason why we defer
creating paths for child-joins.This is not really a full review, mostly because I can't easily figure
out the motivation for all of the changes the patch makes. It makes a
lot of changes in a lot of places, and it's not really very easy to
understand why those changes are necessary. My comments above about
splitting the patch into a series of patches that can potentially be
reviewed and applied independently, with the main patch being the last
in the series, are a suggestion as to how to tackle that. There might
be some work that needs to or could be done on the comments, too. For
example, the patch splits out add_paths_to_append_rel from
set_append_rel_pathlist, but the comments don't say anything helpful
like "we need to do X after Y, because Z". They just say that we do
it. To some extent I think the comments in the optimizer have that
problem generally, so it's not entirely the fault of this patch;
still, the lack of those explanations makes the code reorganization
harder to follow, and might confuse future patch authors, too.Specifically about add_paths_to_append_rel(), what do you expect the
comment to say? It would be obvious why we split that functionality
into a separate function: in fact, we don't necessarily explain why
certain code resides in a separate function in the comments. I think,
that particular comment (or for that matter other such comments in the
optimizer) can be removed altogether, since it just writes the
function names as an "English" sentence. I sometimes find those
comments useful, because I can read just those comments and forget
about the code, making comprehension easy. If highlighting is ON, your
brain habitually ignores the non-comment portions when required. I am
open to suggestions.--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
0001-Refactor-set_append_rel_pathlist.patchapplication/octet-stream; name=0001-Refactor-set_append_rel_pathlist.patchDownload
From cf978fcadc1985c27783c114b8a367fe795efe9e Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 14:45:37 +0530
Subject: [PATCH 01/11] Refactor set_append_rel_pathlist.
set_append_rel_pathlist() creates paths for each child relation and then
creates append paths for the "append" relation. Right now only a base relation
can have children, but with partition-wise join and aggregation a join or an
upper relation can have children as well. While the code to add paths to the
child relations differs for base, join and upper child relations, the code to
create append paths can be shared by all the three relations. Hence separating
it into a new function add_paths_to_append_rel() so that it can be re-used for
all kinds of relations.
---
src/backend/optimizer/path/allpaths.c | 51 ++++++++++++++++++++++++++-------
1 file changed, 41 insertions(+), 10 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 5c18987..d797d6a 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -127,6 +127,8 @@ static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
static int compute_parallel_worker(RelOptInfo *rel, BlockNumber pages);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels);
/*
@@ -1169,19 +1171,11 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
* Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
@@ -1189,7 +1183,6 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -1224,6 +1217,44 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ /* Add Append/MergeAppend paths to the "append" relation. */
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+
+/*
+ * add_paths_to_append_rel
+ * Generate Append/MergeAppend paths for given "append" relation.
+ *
+ * The function collects all parameterizations and orderings supported by the
+ * non-dummy children. For every such parameterization or ordering, it creates
+ * an append path collecting one path from each non-dummy child with given
+ * parameterization or ordering. Similarly it collects partial paths from
+ * non-dummy children to create partial append paths.
+ */
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid = true;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
--
1.7.9.5
0002-Refactor-make_join_rel.patchapplication/octet-stream; name=0002-Refactor-make_join_rel.patchDownload
From 80861ce9a56d639833f015392bb6d4035a9deda2 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 15:41:39 +0530
Subject: [PATCH 02/11] Refactor make_join_rel().
The code in make_join_rel() to add paths to join relation for a given pair of
joining relations can be re-used to add paths to a child join relation, which
do not need the other functionality offered by make_join_rel(). Separate this
code into populate_joinrel_with_paths(). This patch does just refactors
make_join_rel() to pave the way for partition-wise join.
---
src/backend/optimizer/path/joinrels.c | 28 ++++++++++++++++++++++++----
1 file changed, 24 insertions(+), 4 deletions(-)
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 6f3c20b..936ee0c 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -32,6 +32,9 @@ static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
/*
@@ -724,6 +727,27 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Add paths to the given joinrel for given pair of joining relations. The
+ * SpecialJoinInfo provides details about the join and the restrictlist
+ * contains the join clauses and the other clauses applicable for given pair
+ * of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
@@ -868,10 +892,6 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
--
1.7.9.5
0003-Refactor-adjust_appendrel_attrs.patchapplication/octet-stream; name=0003-Refactor-adjust_appendrel_attrs.patchDownload
From 74d38c91f9c37f8c6ede2a1a63ae3fec6731a10d Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 17:22:52 +0530
Subject: [PATCH 03/11] Refactor adjust_appendrel_attrs.
adjust_appendrel_attrs() is used to translate nodes for a parent relation to
those for a child relation by replacing the parent specific nodes like Var
nodes with corresponding nodes specific to the child. Right now this function
works with a single parent-child pair. For partition-wise join and
partition-wise aggregation/grouping, we require to translate nodes for multiple
parent-child pairs. This patch modifies adjust_appendrel_attrs() to work with
multiple parent-child pairs.
---
src/backend/optimizer/path/allpaths.c | 7 +-
src/backend/optimizer/path/equivclass.c | 2 +-
src/backend/optimizer/plan/planner.c | 2 +-
src/backend/optimizer/prep/prepunion.c | 161 ++++++++++++++++++++++---------
src/include/optimizer/prep.h | 2 +-
5 files changed, 121 insertions(+), 53 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index d797d6a..d8fac14 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -862,6 +862,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
ListCell *parentvars;
ListCell *childvars;
ListCell *lc;
+ List *appinfo_list = list_make1(appinfo);
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -903,7 +904,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Assert(IsA(rinfo, RestrictInfo));
childqual = adjust_appendrel_attrs(root,
(Node *) rinfo->clause,
- appinfo);
+ appinfo_list);
childqual = eval_const_expressions(root, childqual);
/* check for flat-out constant */
if (childqual && IsA(childqual, Const))
@@ -1022,11 +1023,11 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
- appinfo);
+ appinfo_list);
childrel->reltarget->exprs = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->reltarget->exprs,
- appinfo);
+ appinfo_list);
/*
* We have to make child entries in the EquivalenceClass data
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index a329dd1..bcce142 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2111,7 +2111,7 @@ add_child_rel_equivalences(PlannerInfo *root,
child_expr = (Expr *)
adjust_appendrel_attrs(root,
(Node *) cur_em->em_expr,
- appinfo);
+ list_make1(appinfo));
/*
* Transform em_relids to match. Note we do *not* do
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 881742f..24a48b8 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -1085,7 +1085,7 @@ inheritance_planner(PlannerInfo *root)
subroot->parse = (Query *)
adjust_appendrel_attrs(root,
(Node *) parse,
- appinfo);
+ list_make1(appinfo));
/*
* If there are securityQuals attached to the parent, move them to the
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 06e843d..6f41979 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -55,7 +55,7 @@
typedef struct
{
PlannerInfo *root;
- AppendRelInfo *appinfo;
+ List *appinfos;
} adjust_appendrel_attrs_context;
static Path *recurse_set_operations(Node *setOp, PlannerInfo *root,
@@ -107,9 +107,9 @@ static Bitmapset *translate_col_privs(const Bitmapset *parent_privs,
List *translated_vars);
static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
-static Relids adjust_relid_set(Relids relids, Index oldrelid, Index newrelid);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
+static Relids adjust_relid_set(Relids relids, List *append_rel_infos);
/*
@@ -1719,10 +1719,10 @@ translate_col_privs(const Bitmapset *parent_privs,
/*
* adjust_appendrel_attrs
- * Copy the specified query or expression and translate Vars referring
- * to the parent rel of the specified AppendRelInfo to refer to the
- * child rel instead. We also update rtindexes appearing outside Vars,
- * such as resultRelation and jointree relids.
+ * Copy the specified query or expression and translate Vars referring to
+ * the parent rels of the specified in the given list of AppendRelInfos to
+ * refer to the corresponding child rel instead. We also update rtindexes
+ * appearing outside Vars, such as resultRelation and jointree relids.
*
* Note: this is only applied after conversion of sublinks to subplans,
* so we don't need to cope with recursion into sub-queries.
@@ -1731,13 +1731,20 @@ translate_col_privs(const Bitmapset *parent_privs,
* maybe we should try to fold the two routines together.
*/
Node *
-adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
+adjust_appendrel_attrs(PlannerInfo *root, Node *node, List *appinfos)
{
Node *result;
adjust_appendrel_attrs_context context;
+ ListCell *lc;
context.root = root;
- context.appinfo = appinfo;
+ context.appinfos = appinfos;
+
+ /*
+ * Catch a caller who wants to adjust expressions, but doesn't pass any
+ * AppendRelInfo.
+ */
+ Assert(appinfos && list_length(appinfos) >= 1);
/*
* Must be prepared to start with a Query or a bare expression tree.
@@ -1745,20 +1752,28 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
if (node && IsA(node, Query))
{
Query *newnode;
+ AppendRelInfo *appinfo;
newnode = query_tree_mutator((Query *) node,
adjust_appendrel_attrs_mutator,
(void *) &context,
QTW_IGNORE_RC_SUBQUERIES);
- if (newnode->resultRelation == appinfo->parent_relid)
+ foreach (lc, appinfos)
{
- newnode->resultRelation = appinfo->child_relid;
- /* Fix tlist resnos too, if it's inherited UPDATE */
- if (newnode->commandType == CMD_UPDATE)
- newnode->targetList =
- adjust_inherited_tlist(newnode->targetList,
- appinfo);
+ appinfo = lfirst(lc);
+
+ if (newnode->resultRelation == appinfo->parent_relid)
+ {
+ newnode->resultRelation = appinfo->child_relid;
+ /* Fix tlist resnos too, if it's inherited UPDATE */
+ if (newnode->commandType == CMD_UPDATE)
+ newnode->targetList =
+ adjust_inherited_tlist(newnode->targetList,
+ appinfo);
+ break;
+ }
}
+
result = (Node *) newnode;
}
else
@@ -1771,13 +1786,29 @@ static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
- AppendRelInfo *appinfo = context->appinfo;
+ List *appinfos = context->appinfos;
+ ListCell *lc;
+
+ /*
+ * Catch a caller who wants to adjust expressions, but doesn't pass any
+ * AppendRelInfo.
+ */
+ Assert(appinfos && list_length(appinfos) >= 1);
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
Var *var = (Var *) copyObject(node);
+ AppendRelInfo *appinfo;
+
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (var->varno == appinfo->parent_relid)
+ break;
+ }
if (var->varlevelsup == 0 &&
var->varno == appinfo->parent_relid)
@@ -1860,29 +1891,54 @@ adjust_appendrel_attrs_mutator(Node *node,
{
CurrentOfExpr *cexpr = (CurrentOfExpr *) copyObject(node);
- if (cexpr->cvarno == appinfo->parent_relid)
- cexpr->cvarno = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (cexpr->cvarno == appinfo->parent_relid)
+ {
+ cexpr->cvarno = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) cexpr;
}
if (IsA(node, RangeTblRef))
{
RangeTblRef *rtr = (RangeTblRef *) copyObject(node);
- if (rtr->rtindex == appinfo->parent_relid)
- rtr->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (rtr->rtindex == appinfo->parent_relid)
+ {
+ rtr->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) rtr;
}
if (IsA(node, JoinExpr))
{
/* Copy the JoinExpr node with correct mutation of subnodes */
JoinExpr *j;
+ AppendRelInfo *appinfo;
j = (JoinExpr *) expression_tree_mutator(node,
adjust_appendrel_attrs_mutator,
(void *) context);
/* now fix JoinExpr's rtindex (probably never happens) */
- if (j->rtindex == appinfo->parent_relid)
- j->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (j->rtindex == appinfo->parent_relid)
+ {
+ j->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) j;
}
if (IsA(node, PlaceHolderVar))
@@ -1895,9 +1951,7 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == 0)
- phv->phrels = adjust_relid_set(phv->phrels,
- appinfo->parent_relid,
- appinfo->child_relid);
+ phv->phrels = adjust_relid_set(phv->phrels, context->appinfos);
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1929,23 +1983,17 @@ adjust_appendrel_attrs_mutator(Node *node,
/* adjust relid sets too */
newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
/*
* Reset cached derivative fields, since these might need to have
@@ -1977,19 +2025,38 @@ adjust_appendrel_attrs_mutator(Node *node,
}
/*
- * Substitute newrelid for oldrelid in a Relid set
+ * Replace parent relids by child relids in the copy of given relid set
+ * according to the given list of AppendRelInfos. The given relid set is
+ * returned as is if it contains no parent in the given list, otherwise, the
+ * given relid set is not changed.
*/
-static Relids
-adjust_relid_set(Relids relids, Index oldrelid, Index newrelid)
+Relids
+adjust_relid_set(Relids relids, List *append_rel_infos)
{
- if (bms_is_member(oldrelid, relids))
+ ListCell *lc;
+ Bitmapset *result = NULL;
+
+ foreach (lc, append_rel_infos)
{
- /* Ensure we have a modifiable copy */
- relids = bms_copy(relids);
- /* Remove old, add new */
- relids = bms_del_member(relids, oldrelid);
- relids = bms_add_member(relids, newrelid);
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ /* Remove parent, add child */
+ if (bms_is_member(appinfo->parent_relid, relids))
+ {
+ /* Make a copy if we are changing the set. */
+ if (!result)
+ result = bms_copy(relids);
+
+ result = bms_del_member(result, appinfo->parent_relid);
+ result = bms_add_member(result, appinfo->child_relid);
+ }
}
+
+ /* Return new set if we modified the given set. */
+ if (result)
+ return result;
+
+ /* Else return the given relids set as is. */
return relids;
}
@@ -2110,5 +2177,5 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
else
Assert(parent_rel->reloptkind == RELOPT_BASEREL);
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, appinfo);
+ return adjust_appendrel_attrs(root, node, list_make1(appinfo));
}
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index 2b20b36..a02e06a 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -53,7 +53,7 @@ extern RelOptInfo *plan_set_operations(PlannerInfo *root);
extern void expand_inherited_tables(PlannerInfo *root);
extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
- AppendRelInfo *appinfo);
+ List *appinfos);
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
--
1.7.9.5
0004-Refactor-build_join_rel.patchapplication/octet-stream; name=0004-Refactor-build_join_rel.patchDownload
From 5606e2526b997606e8485c00fc34ac1f5ccf2fe9 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Mon, 6 Feb 2017 10:58:48 +0530
Subject: [PATCH 04/11] Refactor build_join_rel.
Partition-wise joins do not use build_join_rel() to build child-join relations,
but it still requires code to set foreign relation properties as well as code
to add join relation into PlannerInfo. Separate that code into
set_foreign_rel_properties() and add_join_rel() resp. to be called while
building child joins.
---
src/backend/optimizer/util/relnode.c | 142 ++++++++++++++++++++--------------
1 file changed, 83 insertions(+), 59 deletions(-)
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index adc1db9..160ed6d 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -49,6 +49,9 @@ static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
/*
@@ -327,6 +330,82 @@ find_join_rel(PlannerInfo *root, Relids relids)
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
+ * add_join_rel
+ * Add given join relation to the list of join relations in the given
+ * PlannerInfo. Also add it to the auxiliary hashtable if there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
@@ -424,46 +503,8 @@ build_join_rel(PlannerInfo *root,
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Compute information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
@@ -531,25 +572,8 @@ build_join_rel(PlannerInfo *root,
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
--
1.7.9.5
0005-Add-function-find_param_path_info.patchapplication/octet-stream; name=0005-Add-function-find_param_path_info.patchDownload
From ec2984ab4ea387d5e91fbd354209ff45f114b603 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Mon, 6 Feb 2017 12:14:06 +0530
Subject: [PATCH 05/11] Add function find_param_path_info.
The code to search ParamPathInfo for a set of required outer relations in the
list of ParamPathInfos of a given relation is duplicated in
get_*rel_parampathinfo() functions. Separate this code into
find_param_path_info() and call it from get_*rel_parampathinfo() functions.
---
src/backend/optimizer/util/relnode.c | 46 ++++++++++++++++++++--------------
1 file changed, 27 insertions(+), 19 deletions(-)
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 160ed6d..19982dc 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -52,6 +52,8 @@ static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
static void set_foreign_rel_properties(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
/*
@@ -1047,12 +1049,8 @@ get_baserel_parampathinfo(PlannerInfo *root, RelOptInfo *baserel,
Assert(!bms_overlap(baserel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, baserel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(baserel, required_outer)))
+ return ppi;
/*
* Identify all joinclauses that are movable to this base rel given this
@@ -1289,12 +1287,8 @@ get_joinrel_parampathinfo(PlannerInfo *root, RelOptInfo *joinrel,
*restrict_clauses = list_concat(pclauses, *restrict_clauses);
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, joinrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(joinrel, required_outer)))
+ return ppi;
/* Estimate the number of rows returned by the parameterized join */
rows = get_parameterized_joinrel_size(root, joinrel,
@@ -1333,7 +1327,6 @@ ParamPathInfo *
get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
{
ParamPathInfo *ppi;
- ListCell *lc;
/* Unparameterized paths have no ParamPathInfo */
if (bms_is_empty(required_outer))
@@ -1342,12 +1335,8 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
Assert(!bms_overlap(appendrel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, appendrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(appendrel, required_outer)))
+ return ppi;
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
@@ -1358,3 +1347,22 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
return ppi;
}
+
+/*
+ * Returns a ParamPathInfo for outer relations specified by required_outer, if
+ * already available in the given rel. Returns NULL otherwise.
+ */
+ParamPathInfo *
+find_param_path_info(RelOptInfo *rel, Relids required_outer)
+{
+ ListCell *lc;
+
+ foreach(lc, rel->ppilist)
+ {
+ ParamPathInfo *ppi = (ParamPathInfo *) lfirst(lc);
+ if (bms_equal(ppi->ppi_req_outer, required_outer))
+ return ppi;
+ }
+
+ return NULL;
+}
--
1.7.9.5
0006-Canonical-partition-scheme.patchapplication/octet-stream; name=0006-Canonical-partition-scheme.patchDownload
From 53c7c239715824278c2abe19c15abdb1ed3d7d91 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 10:47:49 +0530
Subject: [PATCH 06/11] Canonical partition scheme.
For a single level partitioned table, annotate RelOptInfo of a partitioned
table with canonical partition scheme. All partitioned tables, with the same
partitioning scheme share the same canonical partitioning scheme. We store the
RelOptInfo's corresponding to the partitions in RelOptInfo of the partitioned
table. Those are arranged in the same order as the partition bound indices in
the partition scheme.
We do not handle multi-level partitioned tables since inheritance hierarchy
does not retain the partition hierarchy. All the partitions at any level
appear as children of the top-level partitioned table. Thus making it hard to
associate a partition relation with corresponding partition bounds.
Multi-level partitioned tables will be handled in a separate patch.
---
src/backend/optimizer/path/allpaths.c | 48 +++++++
src/backend/optimizer/util/plancat.c | 232 +++++++++++++++++++++++++++++++++
src/include/nodes/relation.h | 51 ++++++++
3 files changed, 331 insertions(+)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index d8fac14..0eb56f3 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -829,6 +829,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ int nparts;
/*
* Initialize to compute size estimates for whole append relation.
@@ -850,6 +851,18 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
nattrs = rel->max_attr - rel->min_attr + 1;
parent_attrsizes = (double *) palloc0(nattrs * sizeof(double));
+ /*
+ * For a partitioned table, allocate an array to hold RelOptInfo's of the
+ * partitions. It will be filled while handling the children below.
+ */
+ if (rel->part_scheme)
+ {
+ nparts = rel->part_scheme->nparts;
+ rel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+ }
+ else
+ nparts = 0;
+
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
@@ -879,6 +892,30 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
/*
+ * Two partitioned tables with the same partitioning scheme, have their
+ * partition bounds arranged in the same order. The order of partition
+ * OIDs in RelOptInfo corresponds to the partition bound order. Thus
+ * the OIDs of matching partitions from both the tables are placed at
+ * the same position in the array of partition OIDs in the respective
+ * RelOptInfos. Arranging RelOptInfos of partitions in the same order
+ * as their OIDs makes it easy to find the RelOptInfos of matching
+ * partitions for partition-wise join.
+ */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (rel->part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+ }
+
+ /*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
* baserestrictinfo quals are needed before we can check for
@@ -1130,6 +1167,17 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ if (!rel->part_rels[cnt_parts])
+ elog(ERROR, "could not find the RelOptInfo of a partition with oid %u",
+ rel->part_oids[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7836e6b..01ba885 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_inherits_fn.h"
#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "foreign/fdwapi.h"
@@ -63,6 +64,13 @@ static List *get_relation_constraints(PlannerInfo *root,
bool include_notnull);
static List *build_index_tlist(PlannerInfo *root, IndexOptInfo *index,
Relation heapRelation);
+static List **build_baserel_partition_key_exprs(Relation relation,
+ Index varno);
+static PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+static void get_relation_partition_info(PlannerInfo *root, RelOptInfo *rel,
+ Relation relation, bool inhparent);
+
/*
@@ -412,6 +420,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation, inhparent);
+ /* Collect info about relation's partitioning scheme, if any. */
+ get_relation_partition_info(root, rel, relation, inhparent);
+
heap_close(relation, NoLock);
/*
@@ -1716,3 +1727,224 @@ has_row_triggers(PlannerInfo *root, Index rti, CmdType event)
heap_close(relation, NoLock);
return result;
}
+
+/*
+ * get_relation_partition_info
+ *
+ * Retrieves partitioning information for a given relation.
+ *
+ * Partitioning scheme, partition key expressions and OIDs of partitions are
+ * added to the given RelOptInfo. A partitioned table can participate in the
+ * query as a simple relation or an inheritance parent. Only the later can have
+ * child relations, and hence partitions. From the point of view of the query
+ * optimizer only such relations are considered to be partitioned. Hence
+ * partitioning information is set only for an inheritance parent.
+ */
+static void
+get_relation_partition_info(PlannerInfo *root, RelOptInfo *rel,
+ Relation relation, bool inhparent)
+{
+ /* No partitioning information for an unpartitioned relation. */
+ if (relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE ||
+ !inhparent ||
+ !(rel->part_scheme = find_partition_scheme(root, relation)))
+ {
+ rel->partexprs = NULL;
+ rel->part_rels = NULL;
+ rel->part_oids = NULL;
+ return;
+ }
+
+ rel->partexprs = build_baserel_partition_key_exprs(relation, rel->relid);
+ rel->part_oids = RelationGetPartitionDesc(relation)->oids;
+
+ /*
+ * RelOptInfos of the partitions will be filled in when we build those for
+ * the child relations.
+ */
+ rel->part_rels = NULL;
+ return;
+}
+
+/*
+ * find_partition_scheme
+ *
+ * The function returns a canonical partition scheme which exactly matches the
+ * partitioning properties of the given relation if one exists in the of
+ * canonical partitioning schemes maintained in PlannerInfo. If none of the
+ * existing partitioning schemes match, the function creates a canonical
+ * partition scheme and adds it to the list.
+ *
+ * For an unpartitioned table or for a multi-level partitioned table it returns
+ * NULL. See comments in the function for more details.
+ */
+static PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ int cnt_parts;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /*
+ * For a multi-level partitioned table, we do not retain the partitioning
+ * hierarchy while expanding RTE for the topmost parent. Thus the number of
+ * children as per root->append_rel_list does not match the number of
+ * partitions specified in the partition descriptor and hence the
+ * partitioning scheme of a multi-partitioned table does not reflect the
+ * true picture. So for now, treat a multi-partitioned table as not
+ * partitioned.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (has_subclass(part_desc->oids[cnt_parts]))
+ return NULL;
+ }
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * For types, it suffices to match the type id, mod and collation;
+ * len, byval and align are depedent on the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->parttypid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->parttypmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->parttypcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->boundinfo,
+ part_scheme->boundinfo))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->boundinfo = part_desc->boundinfo;
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopfamily, part_key->partopfamily,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopcintype, part_key->partopcintype,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_types, part_key->parttypid,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ memcpy(part_scheme->key_typmods, part_key->parttypmod,
+ sizeof(int32) * partnatts);
+
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_collations, part_key->parttypcoll,
+ sizeof(Oid) * partnatts);
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_key_exprs
+ *
+ * Collect partition key expressions for a given base relation. The function
+ * converts any single column partition keys into corresponding Var nodes. It
+ * restamps Var nodes in partition key expressions by given varno. The
+ * partition key expressions are returned as an array of single element Lists
+ * to be stored in RelOptInfo of the base relation.
+ */
+static List **
+build_baserel_partition_key_exprs(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (lc == NULL)
+ elog(ERROR, "wrong number of partition key expressions");
+
+ /* Re-stamp the expressions with given varno. */
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 643be54..4f99184 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -15,6 +15,7 @@
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
@@ -261,6 +262,9 @@ typedef struct PlannerInfo
List *distinct_pathkeys; /* distinctClause pathkeys, if any */
List *sort_pathkeys; /* sortClause pathkeys, if any */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
List *initial_rels; /* RelOptInfos we are now trying to join */
/* Use fetch_upper_rel() to get any particular upper rel */
@@ -321,6 +325,38 @@ typedef struct PlannerInfo
((root)->simple_rte_array ? (root)->simple_rte_array[rti] : \
rt_fetch(rti, (root)->parse->rtable))
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting may be partitioned in the same way as the underlying
+ * scan relations. All such relations partitioned in the same way share the
+ * partitioning scheme.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ PartitionBoundInfo boundinfo; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
+typedef struct PartitionSchemeData *PartitionScheme;
/*----------
* RelOptInfo
@@ -531,6 +567,7 @@ typedef struct RelOptInfo
PlannerInfo *subroot; /* if subquery */
List *subplan_params; /* if subquery */
int rel_parallel_workers; /* wanted number of parallel workers */
+ Oid *part_oids; /* OIDs of partitions */
/* Information about foreign tables and foreign joins */
Oid serverid; /* identifies server for the table or join */
@@ -549,6 +586,20 @@ typedef struct RelOptInfo
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For all the partitioned relations. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there may be as many elements
+ * as the number of joining
+ * relations.
+ */
} RelOptInfo;
/*
--
1.7.9.5
0007-Partition-wise-join-tests.patchapplication/octet-stream; name=0007-Partition-wise-join-tests.patchDownload
From 82e4452ff549ede9f34684d363f66291a3bb632b Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 11:57:30 +0530
Subject: [PATCH 07/11] Partition-wise join tests.
This file does not contain tests for joins between multi-leveled partitioned
tables. Those will be added later.
---
src/test/regress/expected/partition_join.out | 4114 ++++++++++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/serial_schedule | 1 +
src/test/regress/sql/partition_join.sql | 515 ++++
4 files changed, 4631 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/partition_join.out
create mode 100644 src/test/regress/sql/partition_join.sql
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..18238fa
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,4114 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(47 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t2.a, t2.b
+ Sort Key: t1_3.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Sort Key: t1_4.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Sort Key: t1_5.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Sort Key: t1_3.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Sort Key: t1_4.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Sort Key: t1_5.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1_2.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(43 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(44 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+--
+-- negative testcases
+--
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index edeb2d6..ac38f50 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -103,7 +103,7 @@ test: publication subscription
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 27a46d7..1bf98a4 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -172,3 +172,4 @@ test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..0322f1e
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,515 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- negative testcases
+--
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
--
1.7.9.5
0008-Partition-wise-join.patchapplication/octet-stream; name=0008-Partition-wise-join.patchDownload
From f3b9529dce1b519cb44ad02c8c8640a7b8c5b73f Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 16:04:03 +0530
Subject: [PATCH 08/11] Partition-wise join
Implement partition-wise join for join between single level partitioned tables.
The details of this technique can be found in optimizer/README, where most of
the implementation has been explained.
We obtain clauses applicable to a child-join by translating corresponding
clauses of the parent. Because child-join can be computed by different
combinations of joining child relations, a given clause is required to be
translated multiple times. In order to reduce the memory consumption, we keep a
repository of child-clauses derived from a parent clause and search in that
repository before translating.
Tests for semi-join, those forcing a merge join for child-join and those
testing lateral join will crash with this patch. The tests testing joins with
partition pruning will also fail. Those crashes and failures are because the
existing code does not expect a child-join to appear in certain cases.
Following patches will fix that code.
---
src/backend/nodes/copyfuncs.c | 9 +
src/backend/optimizer/README | 53 ++++
src/backend/optimizer/path/allpaths.c | 316 ++++++++++++++++---
src/backend/optimizer/path/costsize.c | 3 +
src/backend/optimizer/path/joinpath.c | 21 +-
src/backend/optimizer/path/joinrels.c | 421 ++++++++++++++++++++++++++
src/backend/optimizer/plan/createplan.c | 227 +++++++++++++-
src/backend/optimizer/prep/prepunion.c | 160 ++++++++++
src/backend/optimizer/util/pathnode.c | 113 +++++++
src/backend/optimizer/util/placeholder.c | 55 ++++
src/backend/optimizer/util/relnode.c | 266 +++++++++++++++-
src/backend/utils/misc/guc.c | 28 ++
src/include/nodes/nodes.h | 1 +
src/include/nodes/relation.h | 57 ++++
src/include/optimizer/cost.h | 5 +
src/include/optimizer/pathnode.h | 6 +
src/include/optimizer/paths.h | 5 +
src/include/optimizer/placeholder.h | 2 +
src/include/optimizer/prep.h | 8 +
src/test/regress/expected/partition_join.out | 4 +
src/test/regress/expected/sysviews.out | 29 +-
src/test/regress/sql/partition_join.sql | 5 +
22 files changed, 1724 insertions(+), 70 deletions(-)
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 30d733e..72c021e 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2070,6 +2070,15 @@ _copyRestrictInfo(const RestrictInfo *from)
COPY_SCALAR_FIELD(left_bucketsize);
COPY_SCALAR_FIELD(right_bucketsize);
+ /*
+ * Do not copy parent_rinfo and child_rinfos because 1. they create a
+ * circular dependency between child and parent RestrictInfo 2. dropping
+ * those links just means that we loose some memory optimizations. 3. There
+ * is a possibility that the child and parent RestrictInfots themselves may
+ * have got copied and thus the old links may no longer be valid. The
+ * caller may set up those links itself, if needed.
+ */
+
return newnode;
}
diff --git a/src/backend/optimizer/README b/src/backend/optimizer/README
index fc0fca4..7565ae4 100644
--- a/src/backend/optimizer/README
+++ b/src/backend/optimizer/README
@@ -1076,3 +1076,56 @@ be desirable to postpone the Gather stage until as near to the top of the
plan as possible. Expanding the range of cases in which more work can be
pushed below the Gather (and costing them accurately) is likely to keep us
busy for a long time to come.
+
+Partition-wise joins
+--------------------
+A join between two similarly partitioned tables can be broken down into joins
+between their matching partitions if there exists an equi-join condition
+between the partition keys of the joining tables. The equi-join between
+partition keys implies that for a given row in a given partition of a given
+partitioned table, its joining row, if exists, should exist only in the
+matching partition of the other partitioned table; no row from non-matching
+partitions in the other partitioned table can join with the given row from the
+first table. This condition allows the join between partitioned table to be
+broken into joins between the matching partitions. The resultant join is
+partitioned in the same way as the joining relations, thus allowing an N-way
+join between similarly partitioned tables having equi-join condition between
+their partition keys to be broken down into N-way joins between their matching
+partitions. This technique of breaking down a join between partition tables
+into join between their partitions is called partition-wise join. We will use
+term "partitioned relation" for both partitioned table as well as join between
+partitioned tables which can use partition-wise join technique.
+
+Partitioning properties of a partitioned table are stored in
+PartitionSchemeData structure. Planner maintains a list of canonical partition
+schemes (distinct PartitionSchemeData objects) so that any two partitioned
+relations with same partitioning scheme share the same PartitionSchemeData
+object. This reduces memory consumed by PartitionSchemeData objects and makes
+it easy to compare the partition schemes of joining relations. RelOptInfos of
+partitioned relations hold partition key expressions and the RelOptInfos of
+the partition relations of that relation.
+
+Partition-wise joins are planned in two phases
+
+1. First phase creates the RelOptInfos for joins between matching partitions,
+henceforth referred to as child-joins. The number of paths created for a
+child-join i.e. join between partitions is same as the number of paths created
+for join between parents. That number grows exponentially with the number of
+base relations being joined. The time and memory consumed to create paths for
+each child-join will be proporional to the number of partitions. This will not
+scale well with thousands of partitions. Instead of that we estimate
+partition-wise join cost based on the costs of sampled child-joins. We choose
+child-joins with higher sizes to have realistic estimates. If the number of
+sampled child-joins is same as the number of live child-joins, we create append
+paths as we know costs of all required child-joins. Otherwise we create
+PartitionJoinPaths with cost estimates based on the costs of sampled
+child-joins. While creating append paths or PartitionJoin paths we create paths
+for all the different possible parameterizations and pathkeys available in the
+sampled child-joins.
+
+2. If PartitionJoinPath emerges as the best possible path, we create paths for
+each unsampled child-join. From every child-join we choose the cheapest path
+with same parameterization or pathkeys as the PartitionJoinPath. This path is
+converted into a plan and all the child-join plans are combined using an Append
+or MergeAppend plan as appropriate. We use a fresh memory context for planning
+each unsampled child-join, thus reducing memory consumption.
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 0eb56f3..a024f47 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -15,6 +15,7 @@
#include "postgres.h"
+#include "miscadmin.h"
#include <limits.h>
#include <math.h>
@@ -93,8 +94,8 @@ static void set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
static void set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
static void generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels,
- List *all_child_pathkeys);
+ List *live_childrels, List *all_child_pathkeys,
+ bool partition_join_path);
static Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
RelOptInfo *rel,
Relids required_outer);
@@ -128,8 +129,8 @@ static void recurse_push_qual(Node *setOp, Query *topquery,
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
static int compute_parallel_worker(RelOptInfo *rel, BlockNumber pages);
static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels);
-
+ List *live_childrels, bool partition_join_path);
+static int compare_rel_size(const void *rel1_p, const void *rel2_p);
/*
* make_one_rel
@@ -891,6 +892,12 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel = find_base_rel(root, childRTindex);
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ /* Pass top parent's relids down the inheritance hierarchy. */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
/*
* Two partitioned tables with the same partitioning scheme, have their
* partition bounds arranged in the same order. The order of partition
@@ -900,10 +907,15 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* RelOptInfos. Arranging RelOptInfos of partitions in the same order
* as their OIDs makes it easy to find the RelOptInfos of matching
* partitions for partition-wise join.
+ *
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for building
+ * child-join targetlists.
*/
if (rel->part_scheme)
{
int cnt_parts;
+ AttrNumber attno;
for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
{
@@ -913,6 +925,38 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
rel->part_rels[cnt_parts] = childrel;
}
}
+
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /*
+ * Parent Var for a user defined attribute translates to
+ * child Var.
+ */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
}
/*
@@ -1057,10 +1101,8 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* PlaceHolderVars.) XXX we do not bother to update the cost or width
* fields of childrel->reltarget; not clear if that would be useful.
*/
- childrel->joininfo = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->joininfo,
- appinfo_list);
+ childrel->joininfo = build_child_clauses(root, rel->joininfo,
+ appinfo_list);
childrel->reltarget->exprs = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->reltarget->exprs,
@@ -1079,14 +1121,6 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
- * Note: we could compute appropriate attr_needed data for the child's
- * variables, by transforming the parent's attr_needed through the
- * translated_vars mapping. However, currently there's no need
- * because attr_needed is only examined for base relations not
- * otherrels. So we just leave the child's attr_needed empty.
- */
-
- /*
* If parallelism is allowable for this query in general, see whether
* it's allowable for this childrel in particular. But if we've
* already decided the appendrel is not parallel-safe as a whole,
@@ -1269,10 +1303,9 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
/* Add Append/MergeAppend paths to the "append" relation. */
- add_paths_to_append_rel(root, rel, live_childrels);
+ add_paths_to_append_rel(root, rel, live_childrels, false);
}
-
/*
* add_paths_to_append_rel
* Generate Append/MergeAppend paths for given "append" relation.
@@ -1282,20 +1315,44 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* an append path collecting one path from each non-dummy child with given
* parameterization or ordering. Similarly it collects partial paths from
* non-dummy children to create partial append paths.
+ *
+ * When called on partitioned join relation with partition_join_path = true, it
+ * adds PartitionJoinPath instead of Merge/Append path. This path is costed
+ * based on the costs of sampled child-join and is expanded later into
+ * Merge/Append plan.
*/
static void
add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels)
+ List *live_childrels, bool partition_join_path)
{
List *subpaths = NIL;
bool subpaths_valid = true;
List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
+ bool partial_subpaths_valid;
List *all_child_pathkeys = NIL;
List *all_child_outers = NIL;
ListCell *l;
/*
+ * While creating PartitionJoinPath, we sample paths from only a few child
+ * relations. Even if all of sampled children have partial paths, it's not
+ * guaranteed that all the unsampled children will have partial paths.
+ * Hence we do not create partial PartitionJoinPaths.
+ */
+ partial_subpaths_valid = !partition_join_path ? true : false;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (live_childrels == NIL)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
* For every non-dummy child, remember the cheapest path. Also, identify
* all pathkeys (orderings) and parameterizations (required_outer sets)
* available for the non-dummy member relations.
@@ -1394,7 +1451,17 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel, subpaths,
+ NULL, NIL);
+ else
+ path = (Path *) create_append_path(rel, subpaths, NULL, 0);
+
+ add_path(rel, path);
+ }
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1405,6 +1472,8 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
ListCell *lc;
int parallel_workers = 0;
+ Assert(!partition_join_path);
+
/*
* Decide on the number of workers to request for this append path.
* For now, we just use the maximum value from among the members. It
@@ -1431,7 +1500,7 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
*/
if (subpaths_valid)
generate_mergeappend_paths(root, rel, live_childrels,
- all_child_pathkeys);
+ all_child_pathkeys, partition_join_path);
/*
* Build Append paths for each parameterization seen among the child rels.
@@ -1472,8 +1541,18 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel, subpaths,
+ required_outer, NIL);
+ else
+ path = (Path *) create_append_path(rel, subpaths,
+ required_outer, 0);
+
+ add_path(rel, path);
+ }
}
}
@@ -1499,11 +1578,16 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
* parameterized mergejoin plans, it might be worth adding support for
* parameterized MergeAppends to feed such joins. (See notes in
* optimizer/README for why that might not ever happen, though.)
+ *
+ * When called on partitioned join relation with partition_join_path = true, it
+ * adds PartitionJoinPath with pathkeys instead of MergeAppend path. This path
+ * is costed based on the costs of sampled child-join and is expanded later
+ * into MergeAppend plan.
*/
static void
generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *live_childrels,
- List *all_child_pathkeys)
+ List *all_child_pathkeys, bool partition_join_path)
{
ListCell *lcp;
@@ -1514,6 +1598,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *total_subpaths = NIL;
bool startup_neq_total = false;
ListCell *lcr;
+ Path *path;
/* Select the child paths for this ordering... */
foreach(lcr, live_childrels)
@@ -1560,18 +1645,29 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
accumulate_append_subpath(total_subpaths, cheapest_total);
}
- /* ... and build the MergeAppend paths */
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- startup_subpaths,
- pathkeys,
- NULL));
+ /* ... and build the paths */
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel,
+ startup_subpaths,
+ NULL, pathkeys);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+
if (startup_neq_total)
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- total_subpaths,
- pathkeys,
- NULL));
+ {
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel,
+ total_subpaths,
+ NULL, pathkeys);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ total_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+ }
}
}
@@ -2316,8 +2412,17 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
- * join_search_one_level. After that, we're done creating paths for
- * the joinrel, so run set_cheapest().
+ * join_search_one_level.
+ *
+ * Similarly, create paths for joinrels which used partition-wise join
+ * technique. generate_partition_wise_join_paths() creates paths for
+ * only few of the child-joins with highest sizes. Though we calculate
+ * size of a child-join only once; when it gets created, it may be
+ * deemed empty while considering various join orders within
+ * join_search_one_level.
+ *
+ * After that, we're done creating paths for the joinrel, so run
+ * set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
@@ -2326,6 +2431,9 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
+ /* Create paths for partition-wise joins. */
+ generate_partition_wise_join_paths(root, rel);
+
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
@@ -3011,6 +3119,138 @@ compute_parallel_worker(RelOptInfo *rel, BlockNumber pages)
return parallel_workers;
}
+/*
+ * Function to compare estimated sizes of two relations to be used with
+ * qsort(). Remember that this function is used to sort an array of position
+ * pointers in the array of partitions. So, we have to use double indirection.
+ * See more comments in generate_partition_wise_join_paths() where this
+ * function is used.
+ */
+static int
+compare_rel_size(const void *rel1_p, const void *rel2_p)
+{
+ RelOptInfo *rel1 = **(RelOptInfo ***) rel1_p;
+ RelOptInfo *rel2 = **(RelOptInfo ***) rel2_p;
+
+ return (int) (rel1->rows - rel2->rows);
+}
+
+/*
+ * generate_partition_wise_join_paths
+ *
+ * Create paths representing partition-wise join for given partitioned
+ * join relation.
+ *
+ * The number of paths created for a child-join is same as the number of paths
+ * created for join between parents. That number grows exponentially with the
+ * number of base relations being joined. The time and memory consumed to
+ * create paths for each child-join will be proporional to the number of
+ * partitions. This will not scale well with thousands of partitions. Instead
+ * of that we estimate partition-wise join cost based on the costs of sampled
+ * child-joins. We choose child-joins with higher sizes to have realistic
+ * estimates.
+ *
+ * This must be called after we have considered all joining orders since
+ * certain join orders may allow us to deem a child-join as dummy.
+ */
+void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *sampled_children = NIL;
+ int cnt_parts;
+ int num_part_to_plan;
+ int num_parts;
+ bool partition_join_path = false;
+ int num_dummy_parts = 0;
+ RelOptInfo ***ordered_part_rels;
+ RelOptInfo **part_rels;
+
+ /* Handle only join relations. */
+ if (!IS_JOIN_REL(rel))
+ return;
+
+ /*
+ * If none of the join orders for this relation could use partition-wise
+ * join technique, the join is not partitioned. Reset the partitioning
+ * scheme.
+ */
+ if (!rel->part_rels)
+ rel->part_scheme = NULL;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || IS_DUMMY_REL(rel))
+ return;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ num_parts = rel->part_scheme->nparts;
+ part_rels = rel->part_rels;
+
+ /* Calculate number of child-joins to sample. */
+ num_part_to_plan = num_parts * sample_partition_fraction;
+ if (num_part_to_plan < 1)
+ num_part_to_plan = 1;
+
+ /* Order the child-join relations by their size.
+ * add_paths_to_child_joinrel() needs the position of the child-join in the
+ * array of partition relations. So instead of sorting the actual relations
+ * get their indexes sorted. We use C pointer arithmatic with qsort to do
+ * this.
+ */
+ ordered_part_rels = (RelOptInfo ***) palloc(sizeof(RelOptInfo **) *
+ num_parts);
+ for (cnt_parts = 0; cnt_parts < num_parts; cnt_parts++)
+ ordered_part_rels[cnt_parts] = &part_rels[cnt_parts];
+ qsort(ordered_part_rels, num_parts, sizeof(ordered_part_rels[0]),
+ compare_rel_size);
+
+ /*
+ * Create paths for the child-joins for required number of largest
+ * relations. qsort() returns relations ordered in ascending sizes, so
+ * start from the end of the array.
+ */
+ for (cnt_parts = num_parts - 1; cnt_parts >= 0; cnt_parts--)
+ {
+ int child_no = ordered_part_rels[cnt_parts] - part_rels;
+ RelOptInfo *child_rel = part_rels[child_no];
+
+ /* Create paths for this child. */
+ add_paths_to_child_joinrel(root, rel, child_no);
+
+ /* Dummy children will not be scanned, so ingore those. */
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ sampled_children = lappend(sampled_children, child_rel);
+
+ if (list_length(sampled_children) >= num_part_to_plan)
+ break;
+ }
+ pfree(ordered_part_rels);
+
+ /*
+ * If the number of samples is same as the number of live children, an
+ * append path will do. Otherwise, we will cost the partition-wise join
+ * based on the sampled children using PartitionJoinPath.
+ */
+ if (num_part_to_plan < num_parts - num_dummy_parts)
+ partition_join_path = true;
+
+ /* Add paths for partition-wise join based on the sampled children. */
+ add_paths_to_append_rel(root, rel, sampled_children, partition_join_path);
+
+ if (sampled_children)
+ list_free(sampled_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index a43daa7..c720115 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,9 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
+double partition_wise_plan_weight = DEFAULT_PARTITION_WISE_PLAN_WEIGHT;
+double sample_partition_fraction = DEFAULT_SAMPLE_PARTITION_FRACTION;
typedef struct
{
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index 2897245..f80fb25 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -96,6 +96,19 @@ add_paths_to_joinrel(PlannerInfo *root,
JoinPathExtraData extra;
bool mergejoin_allowed = true;
ListCell *lc;
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between child relations, even if there is a SpecialJoinInfo node for
+ * the join between the topmost parents. Hence while calculating Relids
+ * set representing the restriction, consider relids of topmost parent
+ * of partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
extra.restrictlist = restrictlist;
extra.mergeclause_list = NIL;
@@ -149,16 +162,16 @@ add_paths_to_joinrel(PlannerInfo *root,
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo2->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo2->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo2->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo2->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_righthand))
+ bms_overlap(joinrelids, sjinfo2->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_lefthand));
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 936ee0c..7476e8e 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -14,9 +14,14 @@
*/
#include "postgres.h"
+#include "miscadmin.h"
+#include "nodes/relation.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
@@ -35,6 +40,14 @@ static bool restriction_is_constant_false(List *restrictlist,
static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
RelOptInfo *rel2, RelOptInfo *joinrel,
SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
+static void free_special_join_info(SpecialJoinInfo *sjinfo);
/*
@@ -731,6 +744,9 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
restrictlist);
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
bms_free(joinrelids);
return joinrel;
@@ -1269,3 +1285,408 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
}
return false;
}
+
+/* Free memory used by SpecialJoinInfo. */
+static void
+free_special_join_info(SpecialJoinInfo *sjinfo)
+{
+ bms_free(sjinfo->min_lefthand);
+ bms_free(sjinfo->syn_lefthand);
+ bms_free(sjinfo->syn_righthand);
+ pfree(sjinfo);
+}
+
+/*
+ * Assess whether join between given two partitioned relations can be broken
+ * down into joins between matching partitions; a technique called
+ * "partition-wise join"
+ *
+ * Partition-wise join is possible when a. Joining relations have same
+ * partitioning scheme b. There exists an equi-join between the partition keys
+ * of the two relations.
+ *
+ * Partition-wise join is planned as follows (details: optimizer/README.)
+ *
+ * 1. Create the RelOptInfos for joins between matching partitions i.e
+ * child-joins and estimate sizes of those. This function is responsible for
+ * this phase.
+ *
+ * 2. Add paths representing partition-wise join. The second phase is
+ * implemented by generate_partition_wise_join_paths(). In order to save time
+ * and memory consumed in creating paths for every child-join, we create paths
+ * for only few child-joins.
+ *
+ * 3. Create merge/append plan to combining plans for every child-join,
+ * creating paths for remaining child-joins.
+ *
+ * The RelOptInfo, SpecialJoinInfo and restrictlist for each child join are
+ * obtained by translating the respective parent join structures.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ PartitionScheme part_scheme;
+ PartitionedJoin *partitioned_join;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If any of the joining parent relations is proven empty, either the join
+ * will be empty (INNER join) or will have the inner side all nullified. We
+ * take care of such cases when creating join paths for parent relations.
+ * Nothing to be done here. Also, nothing to do, if the parent join is
+ * proven empty.
+ */
+ if (IS_DUMMY_REL(rel1) || IS_DUMMY_REL(rel2) || IS_DUMMY_REL(joinrel))
+ return;
+
+ /*
+ * Partitioning scheme in join relation indicates a possibility that the
+ * join may be partitioned, but it's not necessary that every pair of
+ * joining relations can use partition-wise join technique. If one of
+ * joining relations turns out to be unpartitioned, this pair of joining
+ * relations can not use partition-wise join technique.
+ */
+ if (!rel1->part_scheme || !rel2->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, this pair of joining relations can not use
+ * partition-wise technique.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ /*
+ * The partition scheme of the join relation should match that of the
+ * joining relations.
+ */
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ /* We should have RelOptInfos of the partitions available. */
+ Assert(rel1->part_rels && rel2->part_rels);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = part_scheme->nparts;
+
+ /*
+ * We do not store information about valid pairs of joining child
+ * relations. The pair of joining relations for a child-join can be derived
+ * from valid pairs of joining parent relations. Amongst the valid pairs of
+ * parent joining relations, only those which result in partitioned join
+ * matter for partition-wise join. Remember those so that we can use them
+ * for creating paths for few child-joins in
+ * generate_partition_wise_join_paths() later.
+ */
+ partitioned_join = (PartitionedJoin *) palloc(sizeof(PartitionedJoin));
+ partitioned_join->rel1 = rel1;
+ partitioned_join->rel2 = rel2;
+ partitioned_join->sjinfo = copyObject(parent_sjinfo);
+ partitioned_join->restrictlist = parent_restrictlist;
+ joinrel->partitioned_joins = lappend(joinrel->partitioned_joins,
+ partitioned_join);
+
+ elog(DEBUG3, "join between relations %s and %s is considered for partition-wise join.",
+ bmsToString(rel1->relids), bmsToString(rel2->relids));
+
+ /* We are done if child RelOptInfos are already created. */
+ if (joinrel->part_rels)
+ return;
+
+ /* Create all the child RelOptInfos. */
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create child join relations for this partitioned join. While doing so,
+ * we estimate sizes of these child join relations. These estimates are
+ * used to find the representative child relations used for costing the
+ * partition-wise join later.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ RelOptInfo *child_joinrel;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ Assert (!joinrel->part_rels[cnt_parts]);
+
+ child_joinrel = build_child_join_rel(root, child_rel1, child_rel2,
+ joinrel, parent_sjinfo->jointype);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, parent_restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, parent_sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+ /*
+ * Set estimates of the child-joinrel's size.
+ */
+ set_joinrel_size_estimates(root, child_joinrel, child_rel1, child_rel2,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the child relations themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+}
+
+/*
+ * add_paths_to_child_join
+ * Add paths to 'child_id'th child of given parent join relation.
+ *
+ * The function creates paths for given child-join by joining corresponding
+ * children of every pair of joining parent relations which produces
+ * partitioned join. Since we create paths only for sampled child-joins, either
+ * of the children being joined may not have paths. In that case, this function
+ * is called recursively to populate paths for those.
+ */
+void
+add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
+ int child_id)
+{
+ ListCell *lc;
+ RelOptInfo *child_joinrel = parent_joinrel->part_rels[child_id];
+
+ Assert(IS_JOIN_REL(parent_joinrel));
+
+ /* If this child relation already has paths, nothing to do. */
+ if (child_joinrel->cheapest_total_path)
+ return;
+
+ /* A dummy relation will have a dummy path as the cheapest path. */
+ Assert(!is_dummy_rel(child_joinrel));
+
+ /*
+ * For every partitioned join order, calculate paths for the joining
+ * child relations and then calculate paths for given child.
+ */
+ foreach (lc, parent_joinrel->partitioned_joins)
+ {
+ PartitionedJoin *pj = lfirst(lc);
+ RelOptInfo *rel1 = pj->rel1;
+ RelOptInfo *rel2 = pj->rel2;
+ RelOptInfo *child_rel1 = rel1->part_rels[child_id];
+ RelOptInfo *child_rel2 = rel2->part_rels[child_id];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+
+ /*
+ * Add paths to joining relation if it is a join itself.
+ * Paths for child base relations are created in
+ * set_append_rel_pathlist().
+ */
+ if (IS_JOIN_REL(pj->rel1))
+ add_paths_to_child_joinrel(root, rel1, child_id);
+
+ if (IS_JOIN_REL(pj->rel2))
+ add_paths_to_child_joinrel(root, rel2, child_id);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, pj->sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, pj->restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /* Add paths for child join. */
+ populate_joinrel_with_paths(root, rel1->part_rels[child_id],
+ rel2->part_rels[child_id], child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /* Add partition-wise join paths for partitioned child-joins. */
+ generate_partition_wise_join_paths(root, child_joinrel);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+
+ set_cheapest(child_joinrel);
+}
+
+/*
+ * Returns true if there exists an equi-join condition for each pair of
+ * partition key from given relations being joined.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ /*
+ * This function should be called when the joining relations have same
+ * partitioning scheme.
+ */
+ Assert(rel1->part_scheme == rel2->part_scheme);
+ Assert(part_scheme);
+
+ num_pks = part_scheme->partnatts;
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip clauses which can not be used for a join. */
+ if (!rinfo->can_join)
+ continue;
+
+ /* Skip clauses which are not equality conditions. */
+ if (rinfo->hashjoinoperator == InvalidOid && !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+
+ /* Match the operands to the relation. */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ /*
+ * If the clause refers to different partition keys from
+ * both relations, it can not be used for partition-wise join.
+ */
+ if (ipk1 != ipk2)
+ continue;
+
+ /*
+ * The clause allows partition-wise join if only it uses the same
+ * operator family as that specified by the partition key.
+ */
+ if (!list_member_oid(rinfo->mergeopfamilies,
+ part_scheme->partopfamily[ipk1]))
+ continue;
+
+ /* Mark the partition key as having an equi-join clause. */
+ pk_has_clause[ipk1] = true;
+ }
+
+ /* Check whether every partition key has an equi-join condition. */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * Find the partition key from the given relation matching the given
+ * expression. If found, return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks;
+
+ /* This function should be called only for partitioned relations. */
+ Assert(rel->part_scheme);
+
+ num_pks = rel->part_scheme->partnatts;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() simplifies multiple
+ * RelabelType nodes into one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 997bdcf..fe6b7f8 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -42,6 +42,7 @@
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
/*
@@ -146,6 +147,8 @@ static CustomScan *create_customscan_plan(PlannerInfo *root,
static NestLoop *create_nestloop_plan(PlannerInfo *root, NestPath *best_path);
static MergeJoin *create_mergejoin_plan(PlannerInfo *root, MergePath *best_path);
static HashJoin *create_hashjoin_plan(PlannerInfo *root, HashPath *best_path);
+static Plan *create_partition_join_plan(PlannerInfo *root,
+ PartitionJoinPath *best_path);
static Node *replace_nestloop_params(PlannerInfo *root, Node *expr);
static Node *replace_nestloop_params_mutator(Node *node, PlannerInfo *root);
static void process_subquery_nestloop_params(PlannerInfo *root,
@@ -369,12 +372,20 @@ create_plan_recurse(PlannerInfo *root, Path *best_path, int flags)
(JoinPath *) best_path);
break;
case T_Append:
- plan = create_append_plan(root,
- (AppendPath *) best_path);
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root,
+ (PartitionJoinPath *)best_path);
+ else
+ plan = create_append_plan(root,
+ (AppendPath *) best_path);
break;
case T_MergeAppend:
- plan = create_merge_append_plan(root,
- (MergeAppendPath *) best_path);
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root,
+ (PartitionJoinPath *)best_path);
+ else
+ plan = create_merge_append_plan(root,
+ (MergeAppendPath *) best_path);
break;
case T_Result:
if (IsA(best_path, ProjectionPath))
@@ -3982,6 +3993,214 @@ create_hashjoin_plan(PlannerInfo *root,
return join_plan;
}
+/*
+ * create_partition_join_plan
+ * Creates Merge/Append plan consisting of join plans for child-join.
+ *
+ * Returns a Plan node.
+ */
+static Plan *
+create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
+{
+ RelOptInfo *joinrel = best_path->path.parent;
+ int nparts;
+ int cnt_parts;
+ List *child_plans = NIL;
+ List *tlist = build_path_tlist(root, &best_path->path);
+ Plan *plan;
+ MemoryContext child_context;
+ MemoryContext old_context;
+ List *pathkeys = best_path->path.pathkeys;
+ StringInfoData mem_context_name;
+
+ /* The relation should be a partitioned join relation. */
+ Assert(IS_JOIN_REL(joinrel) && joinrel->part_scheme &&
+ joinrel->partitioned_joins);
+
+ nparts = joinrel->part_scheme->nparts;
+
+ /* Create MergeAppend plan when result is expected to be ordered. */
+ if (pathkeys)
+ {
+ MergeAppend *node = makeNode(MergeAppend);
+ plan = &node->plan;
+
+ plan->targetlist = tlist;
+
+ /* Compute sorting info, and adjust MergeAppend's tlist as needed. */
+ (void) prepare_sort_from_pathkeys(plan, pathkeys,
+ best_path->path.parent->relids,
+ NULL,
+ true,
+ &node->numCols,
+ &node->sortColIdx,
+ &node->sortOperators,
+ &node->collations,
+ &node->nullsFirst);
+ }
+ else
+ {
+ Append *node = makeNode(Append);
+ plan = &node->plan;
+ plan->targetlist = tlist;
+ }
+
+ /* Fill costs, so that we can cost Sort node, if required. */
+ copy_generic_path_info(plan, (Path *) best_path);
+
+ /*
+ * Create a new memory context for planning child joins. Since this routine
+ * may be called recursively for tables with subpartitions, we use
+ * a unique context name for every level of partition by using the lowest
+ * relid amongst the base relations being joined.
+ */
+ initStringInfo(&mem_context_name);
+ appendStringInfo(&mem_context_name, "%s_%d", "ChildJoinContext",
+ bms_next_member(joinrel->relids, -1));
+ child_context = AllocSetContextCreate(CurrentMemoryContext,
+ pstrdup(mem_context_name.data),
+ ALLOCSET_DEFAULT_SIZES);
+ pfree(mem_context_name.data);
+ resetStringInfo(&mem_context_name);
+
+ /*
+ * Create a paths for all child joins, one child join at a time. The paths
+ * for every child join are independent i.e. one child does not require
+ * paths created for the other. In order to avoid accumulating memory
+ * consumed while creating paths for every child join, we use a fresh
+ * memory context for every child join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_join;
+ Path *child_path = NULL;
+ Plan *child_plan;
+ int numsortkeys;
+ AttrNumber *sortColIdx;
+ Oid *sortOperators;
+ Oid *collations;
+ bool *nullsFirst;
+
+ /*
+ * Create paths for the child join in a separate context, so that we
+ * can reuse the memory used by those paths.
+ */
+ old_context = MemoryContextSwitchTo(child_context);
+
+ add_paths_to_child_joinrel(root, joinrel, cnt_parts);
+
+ child_join = joinrel->part_rels[cnt_parts];
+
+
+ /* Skip empty child. */
+ if (IS_DUMMY_REL(child_join))
+ {
+ MemoryContextSwitchTo(old_context);
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ /*
+ * Search for a child path with pathkeys or parameterization
+ * matching that of the given path.
+ */
+ child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
+ best_path->path.pathkeys,
+ PATH_REQ_OUTER(&best_path->path),
+ TOTAL_COST);
+
+ if (!child_path)
+ elog(ERROR, "Could not find a path with required pathkeys.");
+
+ MemoryContextSwitchTo(old_context);
+
+ /* Create plan for the current child. */
+ child_plan = create_plan_recurse(root, child_path, CP_EXACT_TLIST);
+
+ if (pathkeys)
+ {
+ MergeAppend *node = (MergeAppend *) plan;
+
+ Assert(IsA(node, MergeAppend));
+
+ /* Compute sorting info, and adjust subplan's tlist as needed */
+ child_plan = prepare_sort_from_pathkeys(child_plan, pathkeys,
+ child_path->parent->relids,
+ node->sortColIdx,
+ false,
+ &numsortkeys,
+ &sortColIdx,
+ &sortOperators,
+ &collations,
+ &nullsFirst);
+
+ /*
+ * Check that we got the same sort key information. We just Assert
+ * that the sortops match, since those depend only on the pathkeys;
+ * but it seems like a good idea to check the sort column numbers
+ * explicitly, to ensure the tlists really do match up.
+ */
+ Assert(numsortkeys == node->numCols);
+ if (memcmp(sortColIdx, node->sortColIdx,
+ numsortkeys * sizeof(AttrNumber)) != 0)
+ elog(ERROR, "MergeAppend child's targetlist doesn't match MergeAppend");
+ Assert(memcmp(sortOperators, node->sortOperators,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(collations, node->collations,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(nullsFirst, node->nullsFirst,
+ numsortkeys * sizeof(bool)) == 0);
+
+ /* Now, insert a Sort node if subplan isn't sufficiently ordered */
+ if (!pathkeys_contained_in(pathkeys, child_path->pathkeys))
+ {
+ Sort *sort = make_sort(child_plan, numsortkeys,
+ sortColIdx, sortOperators,
+ collations, nullsFirst);
+ label_sort_with_costsize(root, sort, -1.0);
+ child_plan = (Plan *) sort;
+ }
+ }
+
+ child_plans = lappend(child_plans, child_plan);
+
+ /*
+ * Reset the child_join memory context to reclaim the memory consumed
+ * while creating paths.
+ */
+ MemoryContextResetAndDeleteChildren(child_context);
+ }
+
+ /* Destroy the child context as we do not need it anymore. */
+ Assert(CurrentMemoryContext == old_context);
+ MemoryContextDelete(child_context);
+
+ /* Partitioned relation with all empty children gets a dummy path. */
+ Assert(child_plans != NIL);
+
+ if (IsA(plan, MergeAppend))
+ {
+ MergeAppend *node = (MergeAppend *)plan;
+
+ node->mergeplans = child_plans;
+ }
+ else
+ {
+ Append *node = (Append *)plan;
+
+ Assert(IsA(plan, Append));
+ node->appendplans = child_plans;
+ }
+
+ /* Complete rest of the plan. */
+ plan->qual = NIL;
+ plan->lefttree = NULL;
+ plan->righttree = NULL;
+ return plan;
+}
/*****************************************************************************
*
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 6f41979..676204f 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -2179,3 +2179,163 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
/* Now translate for this child */
return adjust_appendrel_attrs(root, node, list_make1(appinfo));
}
+
+/*
+ * build_child_restrictinfo
+ * Returns a RestrictInfo which is derived from the given RestrictInfo by
+ * applying the parent-child translation specified by the list of
+ * AppendRelInfos.
+ *
+ * The topmost parent's RestrictInfo maintains a list of child RestrictInfos
+ * derived from it. If a suitable RestrictInfo is found in that list, it is
+ * returned as is. If there is no such child RestrictInfo, we translate the given
+ * RestrictInfo using the given list of AppendRelInfos and stick it in the
+ * topmost parent's list before returning it to the caller.
+ */
+RestrictInfo *
+build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
+ List *append_rel_infos)
+{
+ Relids child_required_relids;
+ ListCell *lc;
+ RestrictInfo *parent_rinfo;
+ RestrictInfo *child_rinfo;
+ MemoryContext old_context;
+
+ child_required_relids = adjust_relid_set(rinfo->required_relids,
+ append_rel_infos);
+
+
+ /* Nothing to do, if the clause does not need any translation. */
+ if (bms_equal(child_required_relids, rinfo->required_relids))
+ {
+ bms_free(child_required_relids);
+ return rinfo;
+ }
+
+ /*
+ * Check if we already have the RestrictInfo for the given child in the
+ * topmost parent's RestrictInfo.
+ */
+ parent_rinfo = rinfo->parent_rinfo ? rinfo->parent_rinfo : rinfo;
+ foreach (lc, parent_rinfo->child_rinfos)
+ {
+ child_rinfo = lfirst(lc);
+
+ if (bms_equal(child_rinfo->required_relids, child_required_relids))
+ {
+ bms_free(child_required_relids);
+ return child_rinfo;
+ }
+ }
+
+ /*
+ * We didn't find any child restrictinfo for the given child, translate the
+ * given RestrictInfo and stick it into the parent's list. The clause
+ * expression may get used in plan, so create the child RestrictInfo in the
+ * planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ child_rinfo = (RestrictInfo *) adjust_appendrel_attrs(root, (Node *) rinfo,
+ append_rel_infos);
+ bms_free(child_required_relids);
+ parent_rinfo->child_rinfos = lappend(parent_rinfo->child_rinfos,
+ child_rinfo);
+ child_rinfo->parent_rinfo = parent_rinfo;
+
+ MemoryContextSwitchTo(old_context);
+
+ return child_rinfo;
+}
+
+/*
+ * build_child_clauses
+ * Convenience routine to call build_child_restrictinfo on a list of
+ * clauses.
+ */
+List *
+build_child_clauses(PlannerInfo *root, List *clauses, List *append_rel_infos)
+{
+ List *child_clauses = NIL;
+ ListCell *lc;
+
+ foreach (lc, clauses)
+ {
+ RestrictInfo *parent_rinfo = lfirst(lc);
+ RestrictInfo *child_rinfo;
+
+ Assert(IsA(parent_rinfo, RestrictInfo));
+
+ child_rinfo = build_child_restrictinfo(root, parent_rinfo,
+ append_rel_infos);
+
+ child_clauses = lappend(child_clauses, child_rinfo);
+ }
+
+ return child_clauses;
+}
+
+/*
+ * find_appinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *appinfo_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (bms_is_member(appinfo->child_relid, relids))
+ appinfo_list = lappend(appinfo_list, appinfo);
+ }
+
+ Assert(list_length(appinfo_list) == bms_num_members(relids));
+ return appinfo_list;
+}
+
+/*
+ * Construct the SpecialJoinInfo for a child-join by translating
+ * SpecialJoinInfo for the join between parents. left_relids and right_relids
+ * are the relids of left and right side of the join respectively.
+ */
+SpecialJoinInfo *
+build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids)
+{
+ SpecialJoinInfo *sjinfo = makeNode(SpecialJoinInfo);
+ MemoryContext old_context;
+ List *left_appinfos = find_appinfos_by_relids(root, left_relids);
+ List *right_appinfos = find_appinfos_by_relids(root, right_relids);
+
+ memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
+
+ sjinfo->min_lefthand = adjust_relid_set(sjinfo->min_lefthand,
+ left_appinfos);
+ sjinfo->min_righthand = adjust_relid_set(sjinfo->min_righthand,
+ right_appinfos);
+ sjinfo->syn_lefthand = adjust_relid_set(sjinfo->syn_lefthand,
+ left_appinfos);
+ sjinfo->syn_righthand = adjust_relid_set(sjinfo->syn_righthand,
+ right_appinfos);
+
+ /*
+ * Replace the Var nodes of parent with those of children in expressions.
+ * This function may be called within a temporary context, but the
+ * expressions will be shallow-copied into the plan. Hence copy those in
+ * the planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ sjinfo->semi_rhs_exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ right_appinfos);
+ MemoryContextSwitchTo(old_context);
+
+ list_free(left_appinfos);
+ list_free(right_appinfos);
+
+ return sjinfo;
+}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index f440875..d861a49 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -23,7 +23,9 @@
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
@@ -2154,6 +2156,117 @@ create_hashjoin_path(PlannerInfo *root,
}
/*
+ * create_partition_join_path
+ * Creates a pathnode that represents partition-wise join for given
+ * partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the cost of representative child-joins
+ * paths.
+ */
+PartitionJoinPath *
+create_partition_join_path(PlannerInfo *root, RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer, List *pathkeys)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = pathkeys ? T_MergeAppend : T_Append;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = pathkeys;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ if (!pathkeys)
+ {
+ /*
+ * Startup cost of an append relation is the startup cost of the
+ * first subpath. Assume that the given first child will be the
+ * first child in the final plan as well.
+ */
+ if (lc == list_head(subpaths))
+ subpath_startup_cost = subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else if (pathkeys_contained_in(pathkeys, subpath->pathkeys))
+ {
+ /*
+ * Subpath is adequately ordered, we won't need to sort it. We need
+ * all the subplans to return their respective first rows, before
+ * returning a row. So add the startup costs.
+ */
+ subpath_startup_cost += subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else
+ {
+ /* We'll need to insert a Sort node, so include cost for that */
+ Path sort_path; /* dummy for result of cost_sort */
+
+ cost_sort(&sort_path,
+ root,
+ pathkeys,
+ subpath->total_cost,
+ subpath->parent->tuples,
+ subpath->pathtarget->width,
+ 0.0,
+ work_mem,
+ -1);
+ subpath_startup_cost += sort_path.startup_cost;
+ subpath_total_cost += sort_path.total_cost;
+ }
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ if (!pathkeys)
+ pathnode->path.startup_cost = subpath_startup_cost;
+ else
+ pathnode->path.startup_cost = (subpath_startup_cost * pathnode->path.rows) / subpath_rows;
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ /*
+ * Multiply the costs with scaling factor as specified. Used to encourage
+ * or discourage use of partition-wise join plans.
+ */
+ pathnode->path.startup_cost *= partition_wise_plan_weight;
+ pathnode->path.total_cost *= partition_wise_plan_weight;
+
+ return pathnode;
+}
+
+/*
* create_projection_path
* Creates a pathnode that represents performing a projection.
*
diff --git a/src/backend/optimizer/util/placeholder.c b/src/backend/optimizer/util/placeholder.c
index 698a387..e06bccc 100644
--- a/src/backend/optimizer/util/placeholder.c
+++ b/src/backend/optimizer/util/placeholder.c
@@ -20,6 +20,7 @@
#include "optimizer/pathnode.h"
#include "optimizer/placeholder.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/var.h"
#include "utils/lsyscache.h"
@@ -414,6 +415,10 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
Relids relids = joinrel->relids;
ListCell *lc;
+ /* This function is called only on the parent relations. */
+ Assert(!IS_OTHER_REL(joinrel) && !IS_OTHER_REL(outer_rel) &&
+ !IS_OTHER_REL(inner_rel));
+
foreach(lc, root->placeholder_list)
{
PlaceHolderInfo *phinfo = (PlaceHolderInfo *) lfirst(lc);
@@ -459,3 +464,53 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
}
}
}
+
+/*
+ * add_placeholders_to_child_joinrel
+ * Translate the PHVs in parent's targetlist and add them to the child's
+ * targetlist. Also adjust the cost
+ */
+void
+add_placeholders_to_child_joinrel(PlannerInfo *root, RelOptInfo *childrel,
+ RelOptInfo *parentrel)
+{
+ ListCell *lc;
+
+ /* This function is called only for join relations. */
+ Assert(IS_JOIN_REL(childrel) && IS_JOIN_REL(parentrel));
+
+ /* Ensure child relations is really what it claims to be. */
+ Assert(IS_OTHER_REL(childrel));
+
+ foreach (lc, parentrel->reltarget->exprs)
+ {
+ PlaceHolderVar *phv = lfirst(lc);
+
+ if (IsA(phv, PlaceHolderVar))
+ {
+ /*
+ * In case the placeholder Var refers to any of the parent
+ * relations, translate it to refer to the corresponding child.
+ */
+ if (bms_overlap(phv->phrels, parentrel->relids) &&
+ childrel->reloptkind == RELOPT_OTHER_JOINREL)
+ {
+ List *append_rel_infos;
+
+ append_rel_infos = find_appinfos_by_relids(root,
+ childrel->relids);
+ phv = (PlaceHolderVar *) adjust_appendrel_attrs(root,
+ (Node *) phv,
+ append_rel_infos);
+ }
+
+ childrel->reltarget->exprs = lappend(childrel->reltarget->exprs,
+ phv);
+ }
+ }
+
+ /* Adjust the cost and width of child targetlist. */
+ childrel->reltarget->cost.startup = parentrel->reltarget->cost.startup;
+ childrel->reltarget->cost.per_tuple = parentrel->reltarget->cost.per_tuple;
+ childrel->reltarget->width = parentrel->reltarget->width;
+}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 19982dc..1eed987 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -23,6 +23,7 @@
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
#include "utils/hsearch.h"
@@ -54,6 +55,9 @@ static void set_foreign_rel_properties(RelOptInfo *joinrel,
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
Relids required_outer);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
/*
@@ -434,6 +438,9 @@ build_join_rel(PlannerInfo *root,
RelOptInfo *joinrel;
List *restrictlist;
+ /* This function should be used only for join between parents. */
+ Assert(!IS_OTHER_REL(outer_rel) && !IS_OTHER_REL(inner_rel));
+
/*
* See if we already have a joinrel for this set of base rels.
*/
@@ -532,6 +539,10 @@ build_join_rel(PlannerInfo *root,
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
@@ -594,6 +605,126 @@ build_join_rel(PlannerInfo *root,
return joinrel;
}
+ /*
+ * build_child_join_rel
+ * Builds RelOptInfo for joining given two child relations from RelOptInfo
+ * representing the join between their parents.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of child relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for child join
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_appinfos': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ JoinType jointype)
+{
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel) && IS_OTHER_REL(inner_rel));
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Compute information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /* Build targetlist */
+ build_joinrel_tlist(root, joinrel, outer_rel);
+ build_joinrel_tlist(root, joinrel, inner_rel);
+ /* Add placeholder variables. */
+ add_placeholders_to_child_joinrel(root, joinrel, parent_joinrel);
+
+ /* Construct joininfo list. */
+ joinrel->joininfo = build_child_clauses(root, parent_joinrel->joininfo,
+ find_appinfos_by_relids(root,
+ joinrel->relids));
+
+ /*
+ * Lateral relids referred in child join will be same as that referred in
+ * the parent relation. Throw any partial result computed while building
+ * the targetlist.
+ */
+ bms_free(joinrel->direct_lateral_relids);
+ bms_free(joinrel->lateral_relids);
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, jointype);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ /* We build the join only once. */
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
/*
* min_join_parameterization
*
@@ -649,9 +780,15 @@ static void
build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *vars;
+ /* attrs_needed refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(vars, input_rel->reltarget->exprs)
{
Var *var = (Var *) lfirst(vars);
@@ -667,23 +804,47 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
/*
* Otherwise, anything in a baserel or joinrel targetlist ought to be
- * a Var. (More general cases can only appear in appendrel child
- * rels, which will never be seen here.)
+ * a Var or ConvertRowtypeExpr introduced while translating parent
+ * targetlist to that of the child.
*/
- if (!IsA(var, Var))
+ if (IsA(var, Var))
+ {
+ /* Get the Var's original base rel */
+ baserel = find_base_rel(root, var->varno);
+
+ /* Is it still needed above this joinrel? */
+ ndx = var->varattno - baserel->min_attr;
+ }
+ else if (IsA(var, ConvertRowtypeExpr))
+ {
+ ConvertRowtypeExpr *child_expr = (ConvertRowtypeExpr *) var;
+ Var *childvar = (Var *) child_expr->arg;
+
+ /*
+ * Child's whole-row references are converted to that of parent
+ * using ConvertRowtypeExpr. In this case, the argument to
+ * ConvertRowtypeExpr is expected to be a whole-row reference of
+ * the child.
+ */
+ Assert(IsA(childvar, Var) && childvar->varattno == 0);
+
+ baserel = find_base_rel(root, childvar->varno);
+ ndx = 0 - baserel->min_attr;
+ }
+ else
elog(ERROR, "unexpected node type in rel targetlist: %d",
(int) nodeTag(var));
- /* Get the Var's original base rel */
- baserel = find_base_rel(root, var->varno);
-
- /* Is it still needed above this joinrel? */
- ndx = var->varattno - baserel->min_attr;
if (bms_nonempty_difference(baserel->attr_needed[ndx], relids))
{
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs, var);
- /* Vars have cost zero, so no need to adjust reltarget->cost */
+
+ /*
+ * Vars have cost zero, so no need to adjust reltarget->cost. Even
+ * if, it's a ConvertRowtypeExpr, it will be computed only for the
+ * base relation, costing nothing for a join.
+ */
joinrel->reltarget->width += baserel->attr_widths[ndx];
}
}
@@ -820,6 +981,9 @@ subbuild_joinrel_joinlist(RelOptInfo *joinrel,
{
ListCell *l;
+ /* Expected to be called only for join between parent relations. */
+ Assert(joinrel->reloptkind == RELOPT_JOINREL);
+
foreach(l, joininfo_list)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(l);
@@ -1366,3 +1530,85 @@ find_param_path_info(RelOptInfo *rel, Relids required_outer)
return NULL;
}
+
+/*
+ * build_joinrel_partition_info
+ * If the join between given partitioned relations is possibly partitioned
+ * set the partitioning scheme and partition keys expressions for the
+ * join.
+ *
+ * If the two relations have same partitioning scheme, their join may be
+ * partitioned and will follow the same partitioning scheme as the joining
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /* Nothing to do if partition-wise join technique is disabled. */
+ if (!enable_partition_wise_join)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * The join is not partitioned, if any of the relations being joined are
+ * not partitioned or they do not have same partitioning scheme.
+ */
+ if (!outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel, hence it should
+ * not have partition scheme, partition key expressions and array for
+ * storing child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ /*
+ * Join relation is partitioned using same partitioning scheme as the
+ * joining relations.
+ */
+ joinrel->part_scheme = outer_rel->part_scheme;
+ num_pks = joinrel->part_scheme->partnatts;
+
+ /*
+ * Construct partition keys for the join.
+ *
+ * An INNER join between two partitioned relations is partition by key
+ * expressions from both the relations. For tables A and B partitioned by a and b
+ * respectively, (A INNER JOIN B ON A.a = B.b) is partitioned by both A.a
+ * and B.b.
+ *
+ * An OUTER join like (A LEFT JOIN B ON A.a = B.b) may produce rows with
+ * B.b NULL. These rows may not fit the partitioning conditions imposed on
+ * B.b. Hence, strictly speaking, the join is not partitioned by B.b.
+ * Strictly speaking, partition keys of an OUTER join should include
+ * partition key expressions from the OUTER side only. Consider a join like
+ * (A LEFT JOIN B on (A.a = B.b) LEFT JOIN C ON B.b = C.c. If we do not
+ * include B.b as partition key expression for (AB), it prohibits us from
+ * using partition-wise join when joining (AB) with C as there is no
+ * equi-join between partition keys of joining relations. But two NULL
+ * values are never equal and no two rows from mis-matching partitions can
+ * join. Hence it's safe to include B.b as partition key expression for
+ * (AB), even though rows in (AB) are not strictly partitioned by B.b.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index de85eca..afd0c23 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -901,6 +901,15 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
@@ -2947,6 +2956,25 @@ static struct config_real ConfigureNamesReal[] =
},
{
+ {"partition_wise_plan_weight", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Multiplication factor for partition-wise plan costs."),
+ NULL
+ },
+ &partition_wise_plan_weight,
+ DEFAULT_PARTITION_WISE_PLAN_WEIGHT, 0, DBL_MAX,
+ NULL, NULL, NULL
+ },
+ {
+ {"sample_partition_fraction", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Fraction of partitions to be used as sample for calculating total cost of partition-wise plans."),
+ NULL
+ },
+ &sample_partition_fraction,
+ DEFAULT_SAMPLE_PARTITION_FRACTION, 0, 1,
+ NULL, NULL, NULL
+ },
+
+ {
{"bgwriter_lru_multiplier", PGC_SIGHUP, RESOURCES_BGWRITER,
gettext_noop("Multiple of the average buffer usage to free per round."),
NULL
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 95dd8ba..292d9a6 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -240,6 +240,7 @@ typedef enum NodeTag
T_NestPath,
T_MergePath,
T_HashPath,
+ T_PartitionJoinPath,
T_AppendPath,
T_MergeAppendPath,
T_ResultPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 4f99184..146d53b 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -391,6 +391,11 @@ typedef struct PartitionSchemeData *PartitionScheme;
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing joins between child relations of
+ * different partitioned tables. These relations are not added to
+ * join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
@@ -512,10 +517,19 @@ typedef enum RelOptKind
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(rel) \
+ ((rel)->reloptkind == RELOPT_OTHER_MEMBER_REL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
+#define IS_JOIN_REL(rel) \
+ ((rel)->reloptkind == RELOPT_JOINREL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
@@ -600,6 +614,14 @@ typedef struct RelOptInfo
* as the number of joining
* relations.
*/
+
+ /* For joins between partitioned tables. */
+ List *partitioned_joins; /* List of join orders which yield
+ * relations partitioned by above
+ * partition scheme.
+ */
+ /* Set only for "other" base or "other" join relations. */
+ Relids top_parent_relids; /* Relids of topmost parents. */
} RelOptInfo;
/*
@@ -1540,6 +1562,14 @@ typedef struct LimitPath
Node *limitCount; /* COUNT parameter, or NULL if none */
} LimitPath;
+/*
+ * PartitionJoinPath represents partition-wise join between two partitioned
+ * tables.
+ */
+typedef struct PartitionJoinPath
+{
+ Path path;
+} PartitionJoinPath;
/*
* Restriction clause info.
@@ -1747,6 +1777,18 @@ typedef struct RestrictInfo
/* cache space for hashclause processing; -1 if not yet set */
Selectivity left_bucketsize; /* avg bucketsize of left side */
Selectivity right_bucketsize; /* avg bucketsize of right side */
+
+ /*
+ * Repository to locate child RestrictInfos derived from parent
+ * RestrictInfo. Every derived child RestrictInfo points to the parent
+ * RestrictInfo from which it is derived. Parent RestrictInfo maintains a
+ * list of all derived child RestrictInfos. So only one of the following
+ * should be set.
+ */
+ List *child_rinfos; /* RestrictInfos derived for children. */
+ struct RestrictInfo *parent_rinfo; /* Parent restrictinfo this
+ * RestrictInf is derived from.
+ */
} RestrictInfo;
/*
@@ -1869,6 +1911,21 @@ typedef struct SpecialJoinInfo
} SpecialJoinInfo;
/*
+ * Partitioned join information
+ *
+ * Saves information about relations which can be joined partition-wise and
+ * thus produce result which is partitioned by the partition scheme of the
+ * relation.
+ */
+typedef struct PartitionedJoin
+{
+ RelOptInfo *rel1;
+ RelOptInfo *rel2;
+ SpecialJoinInfo *sjinfo; /* SpecialJoinInfo applicable. */
+ List *restrictlist; /* applicable join clauses. */
+} PartitionedJoin;
+
+/*
* Append-relation info.
*
* When we expand an inheritable table or a UNION-ALL subselect into an
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 0e68264..a13eff1 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -30,6 +30,8 @@
#define DEFAULT_PARALLEL_SETUP_COST 1000.0
#define DEFAULT_EFFECTIVE_CACHE_SIZE 524288 /* measured in pages */
+#define DEFAULT_PARTITION_WISE_PLAN_WEIGHT 1
+#define DEFAULT_SAMPLE_PARTITION_FRACTION 0.01
typedef enum
{
@@ -66,7 +68,10 @@ extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
+extern double partition_wise_plan_weight;
+extern double sample_partition_fraction;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 7b41317..81d637a 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -229,6 +229,9 @@ extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
+extern PartitionJoinPath *create_partition_join_path(PlannerInfo *root,
+ RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer, List *pathkeys);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
@@ -271,5 +274,8 @@ extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, JoinType jointype);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 81a9be7..7ad19be 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -53,6 +53,8 @@ extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
extern void generate_gather_paths(PlannerInfo *root, RelOptInfo *rel);
+extern void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
#ifdef OPTIMIZER_DEBUG
extern void debug_print_rel(PlannerInfo *root, RelOptInfo *rel);
@@ -106,6 +108,9 @@ extern bool have_join_order_restriction(PlannerInfo *root,
RelOptInfo *rel1, RelOptInfo *rel2);
extern bool have_dangerous_phv(PlannerInfo *root,
Relids outer_relids, Relids inner_params);
+extern void add_paths_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *parent_joinrel,
+ int child_id);
/*
* equivclass.c
diff --git a/src/include/optimizer/placeholder.h b/src/include/optimizer/placeholder.h
index 11e6403..8598268 100644
--- a/src/include/optimizer/placeholder.h
+++ b/src/include/optimizer/placeholder.h
@@ -28,5 +28,7 @@ extern void fix_placeholder_input_needed_levels(PlannerInfo *root);
extern void add_placeholders_to_base_rels(PlannerInfo *root);
extern void add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+extern void add_placeholders_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *childrel, RelOptInfo *parentrel);
#endif /* PLACEHOLDER_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index a02e06a..5832130 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -57,5 +57,13 @@ extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
+extern RestrictInfo *build_child_restrictinfo(PlannerInfo *root,
+ RestrictInfo *rinfo, List *append_rel_infos);
+extern List *build_child_clauses(PlannerInfo *root, List *clauses,
+ List *append_rel_infos);
+extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
+extern SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids);
#endif /* PREP_H */
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
index 18238fa..79779d6 100644
--- a/src/test/regress/expected/partition_join.out
+++ b/src/test/regress/expected/partition_join.out
@@ -2,6 +2,10 @@
-- PARTITION_JOIN
-- Test partition-wise join between partitioned tables
--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
--
-- partitioned by a single column
--
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index d48abd7..c6c1405 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -70,20 +70,21 @@ select count(*) >= 0 as ok from pg_prepared_xacts;
-- This is to record the prevailing planner enable_foo settings during
-- a regression test run.
select name, setting from pg_settings where name like 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
-- Test that the pg_timezone_names and pg_timezone_abbrevs views are
-- more-or-less working. We can't test their contents in any great detail
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
index 0322f1e..9b2baeb 100644
--- a/src/test/regress/sql/partition_join.sql
+++ b/src/test/regress/sql/partition_join.sql
@@ -3,6 +3,11 @@
-- Test partition-wise join between partitioned tables
--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
+
--
-- partitioned by a single column
--
--
1.7.9.5
0009-Adjust-join-related-to-code-to-accept-child-relation.patchapplication/octet-stream; name=0009-Adjust-join-related-to-code-to-accept-child-relation.patchDownload
From 4d823ad9179e98a206de9c2b5a8c8ea30415abb6 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 17:16:46 +0530
Subject: [PATCH 09/11] Adjust join related to code to accept child relations.
Existing join related code doesn't expect child relations to be joined. This
patch contains various fixes to change that.
1. Uniqe-ifying joining relations.
=================================
For semi-joins we unique-ify the joining relations, which tries to estimate
nummber of unique values using estimate_num_groups(). This function doesn't
expect a Var from a child relation and contained an assertion to that effect.
With partition-wise joins, we may compute a join between child relations. This
commit changes that assertion to include child relation. The function doesn't
need any change other than that to accomodate child relations.
2. OUTER joins require dummy child relations to have targetlist.
================================================================
We need a targetlist defining nullable columns for an outer join, even if the
relation on the nullable side is deemed to be empty. Prior to partition-wise
join an empty child relation never had a targetlist since it was eliminated
from planning. But with partition-wise join an empty child relation may
participate in an outer join with another non-empty child relation. Hence set
targetlist for a child relation even if it's dummy.
3. prepare_sort_from_pathkeys fixes.
====================================
Before partition-wise join feature were never required to be directly sorted,
let's say for merge joins. With partition-wise join feature, the child
relations will participate directly in the join and also need to be sorted
directly for the purpose of merge join. In order to sort a relation, we use
pathkeys. The expression on which to sort a particular relation is provided by
the equivalence member corresponding to that relation in the equivalence class
referred by the pathkeys. Since the code doesn't expect child relations to
bubble up to the sorting, the function prepare_sort_from_pathkeys() skips any
child members (those set with em_is_child) unless the caller specifically asks
for child relations by passing relids. make_sort_from_pathkeys() calls
prepare_sort_from_pathkeys() to create Sort plan for outer and inner plans
without passing relids of the relation to be sorted. For partition-wise joins
the outer and inner plans produce child relations and thus
prepare_sort_from_pathkeys() does not find equivalence members since it skips
child members for the want of relids. This particular instance can be fixed by
passing outer/inner_path->parent->relids to prepare_sort_from_pathkeys().
All the callers of prepare_sort_from_pathkeys() viz.
create_merge_append_plan(), create_merge_append_plan(),
create_windowagg_plan() except make_sort_from_pathkeys() pass relids to
prepare_sort_from_pathkeys(). make_sort_from_pathkeys() as well passes those
with this patch.
make_sort_from_pathkeys() itself doesn't know the relids of relation being
sorted. It just gets the plan. Hence we need to pass relids to
make_sort_from_pathkeys() and thus change each of its callers to pass relids,
if required.
It has two callers as of now.
1. create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags): does
not handle child relations yet, so doesn't need any change.
2. create_mergejoin_plan(PlannerInfo *root, MergePath *best_path):
It requires this change and the relids can be obtained from the outer and inner
path's parent RelOptInfo.
4. Handling em_is_child cases.
==============================
Right now, when comparing relids for child relations, only exact match is
considered. This is fine as long as em_relids has only a single member in it
and the passed in relids has only a single member in it. But with
partition-wise join, relids can have multiple members and em_relids may not
exactly match the given relids. But we need to find the member which covers
subset of given relids.
---
src/backend/optimizer/path/allpaths.c | 41 +++++++++++++++++--------------
src/backend/optimizer/plan/createplan.c | 28 +++++++++++++--------
src/backend/utils/adt/selfuncs.c | 3 ++-
3 files changed, 42 insertions(+), 30 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index a024f47..7e806c1 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -960,11 +960,27 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
- * We have to copy the parent's targetlist and quals to the child,
- * with appropriate substitution of variables. However, only the
- * baserestrictinfo quals are needed before we can check for
- * constraint exclusion; so do that first and then check to see if we
- * can disregard this child.
+ * Copy/Modify targetlist. Even if this child is deemed empty, we need
+ * its targetlist in case it falls on nullable side in a child-join
+ * because of partition-wise join.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ appinfo_list);
+
+ /*
+ * We have to copy the parent's quals to the child, with appropriate
+ * substitution of variables. However, only the baserestrictinfo quals
+ * are needed before we can check for constraint exclusion; so do that
+ * first and then check to see if we can disregard this child.
*
* The child rel's targetlist might contain non-Var expressions, which
* means that substitution into the quals could produce opportunities
@@ -1091,22 +1107,9 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying targetlist and join quals. */
childrel->joininfo = build_child_clauses(root, rel->joininfo,
appinfo_list);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo_list);
/*
* We have to make child entries in the EquivalenceClass data
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index fe6b7f8..d0705dc 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -245,7 +245,8 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
@@ -1555,7 +1556,7 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
@@ -3572,6 +3573,8 @@ create_mergejoin_plan(PlannerInfo *root,
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
@@ -3635,8 +3638,10 @@ create_mergejoin_plan(PlannerInfo *root,
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
@@ -3647,8 +3652,10 @@ create_mergejoin_plan(PlannerInfo *root,
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
@@ -5630,11 +5637,11 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
@@ -5745,10 +5752,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
@@ -5769,9 +5776,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
@@ -5781,7 +5789,7 @@ make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index fa32e9e..c833846 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3427,7 +3427,8 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
if (rel->tuples > 0)
{
/*
--
1.7.9.5
0010-Parameterized-path-fixes.patchapplication/octet-stream; name=0010-Parameterized-path-fixes.patchDownload
From 3d7d73e983c3d18b3ac87fecc33b22fee0cc3448 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 17:25:25 +0530
Subject: [PATCH 10/11] Parameterized path fixes.
We do not create merge or hash join paths when the inner path is parameterized
by the outer and vice-versa. Parameterization information in path refers to the
top-most parent relation. Current tests (PATH_PARAM_BY_REL) to avoid joining
such paths fail while joining child relations; the paths from either child may
be paramterized by other's parent. Modify the tests to consider paths
parameterized by parent as parameterized by any of its child.
If the inner path is parameterized by outer path, we can create a nested loop
join using those two paths with inner relation parameterized by the outer
relation. For LATERAL JOINs this is the only legal way to plan a join. In case
of partitioned joins, the lateral references refer to the topmost parent and
hence inner paths are parameterized by the topmost parent. In such cases, it's
possible to translate the inner path to be parameterized by
the child and create nested loop join. When presented with a pair of child
relation paths, where the inner paths is parameterized by the parent of outer
child, this patch translates the path to be parameterized by the outer child
and creates a nested loop join path.
The function reparameterize_path_by_child() needs to call adjust_relid_set() to
substitute parent relids by child relids in Path::param_info::ppi_req_outer.
Hence "extern"alized that function. Since there is already another
static adjust_relid_set() in rewriteManip.c, renamed this one to
adjust_child_relids().
Also "extern"alized find_param_path_info() required by
reparameterize_path_by_child().
---
src/backend/optimizer/path/joinpath.c | 33 +++++-
src/backend/optimizer/prep/prepunion.c | 42 ++++----
src/backend/optimizer/util/pathnode.c | 180 ++++++++++++++++++++++++++++++++
src/backend/optimizer/util/relnode.c | 2 -
src/include/optimizer/pathnode.h | 4 +
src/include/optimizer/prep.h | 1 +
6 files changed, 237 insertions(+), 25 deletions(-)
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index f80fb25..4d4a183 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -25,9 +25,19 @@
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+/*
+ * Paths parameterized by the parent can be considered to be parameterized by
+ * any of its child.
+ */
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
@@ -301,6 +311,27 @@ try_nestloop_path(PlannerInfo *root,
JoinCostWorkspace workspace;
/*
+ * Since result produced by a child is part of the result produced by its
+ * topmost parent and has same properties, the parameters representing that
+ * parent may be substituted by values from a child. Hence expressions and
+ * hence paths using those expressions, parameterized by a parent can be
+ * said to be parameterized by any of its child. For a join between child
+ * relations, if the inner path is parameterized by the parent of the outer
+ * relation, create a nestloop join path with inner relation parameterized
+ * by the outer relation by translating the inner path to be parameterized
+ * by the outer child relation.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_by_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 676204f..d459e95 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -109,7 +109,6 @@ static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
-static Relids adjust_relid_set(Relids relids, List *append_rel_infos);
/*
@@ -1951,7 +1950,7 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == 0)
- phv->phrels = adjust_relid_set(phv->phrels, context->appinfos);
+ phv->phrels = adjust_child_relids(phv->phrels, context->appinfos);
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1982,17 +1981,17 @@ adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_mutator((Node *) oldinfo->orclause, context);
/* adjust relid sets too */
- newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
+ newinfo->clause_relids = adjust_child_relids(oldinfo->clause_relids,
context->appinfos);
- newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
+ newinfo->required_relids = adjust_child_relids(oldinfo->required_relids,
context->appinfos);
- newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
+ newinfo->outer_relids = adjust_child_relids(oldinfo->outer_relids,
context->appinfos);
- newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
+ newinfo->nullable_relids = adjust_child_relids(oldinfo->nullable_relids,
context->appinfos);
- newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
+ newinfo->left_relids = adjust_child_relids(oldinfo->left_relids,
context->appinfos);
- newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
+ newinfo->right_relids = adjust_child_relids(oldinfo->right_relids,
context->appinfos);
/*
@@ -2026,15 +2025,18 @@ adjust_appendrel_attrs_mutator(Node *node,
/*
* Replace parent relids by child relids in the copy of given relid set
- * according to the given list of AppendRelInfos. The given relid set is
- * returned as is if it contains no parent in the given list, otherwise, the
- * given relid set is not changed.
+ * according to the given list of AppendRelInfos.
*/
Relids
-adjust_relid_set(Relids relids, List *append_rel_infos)
+adjust_child_relids(Relids relids, List *append_rel_infos)
{
ListCell *lc;
- Bitmapset *result = NULL;
+
+ /*
+ * The new relids set may be expected to be in a memory context different
+ * from the given one. Make a copy here.
+ */
+ Bitmapset *result = bms_copy(relids);
foreach (lc, append_rel_infos)
{
@@ -2043,10 +2045,6 @@ adjust_relid_set(Relids relids, List *append_rel_infos)
/* Remove parent, add child */
if (bms_is_member(appinfo->parent_relid, relids))
{
- /* Make a copy if we are changing the set. */
- if (!result)
- result = bms_copy(relids);
-
result = bms_del_member(result, appinfo->parent_relid);
result = bms_add_member(result, appinfo->child_relid);
}
@@ -2202,7 +2200,7 @@ build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
RestrictInfo *child_rinfo;
MemoryContext old_context;
- child_required_relids = adjust_relid_set(rinfo->required_relids,
+ child_required_relids = adjust_child_relids(rinfo->required_relids,
append_rel_infos);
@@ -2313,13 +2311,13 @@ build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
- sjinfo->min_lefthand = adjust_relid_set(sjinfo->min_lefthand,
+ sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
left_appinfos);
- sjinfo->min_righthand = adjust_relid_set(sjinfo->min_righthand,
+ sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
right_appinfos);
- sjinfo->syn_lefthand = adjust_relid_set(sjinfo->syn_lefthand,
+ sjinfo->syn_lefthand = adjust_child_relids(sjinfo->syn_lefthand,
left_appinfos);
- sjinfo->syn_righthand = adjust_relid_set(sjinfo->syn_righthand,
+ sjinfo->syn_righthand = adjust_child_relids(sjinfo->syn_righthand,
right_appinfos);
/*
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index d861a49..f322320 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -3388,3 +3388,183 @@ reparameterize_path(PlannerInfo *root, Path *path,
}
return NULL;
}
+
+/*
+ * reparameterize_path_by_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ *
+ * The cost, number of rows, width and parallel path properties depend upon
+ * path->parent, which does not change during the translation. Hence those
+ * members are copied as they are.
+ */
+
+Path *
+reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+ Relids required_outer;
+
+ /*
+ * If the path is not parameterized by parent of the given relation or it it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ required_outer = adjust_child_relids(old_ppi->ppi_req_outer, child_aris);
+
+ /* If we already have a PPI for this parameterization, just return it */
+ new_ppi = find_param_path_info(new_path->parent, required_outer);
+
+ /* If not build a new one and link it to the list of PPIs. */
+ if (!new_ppi)
+ {
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = required_outer;
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = build_child_clauses(root, old_ppi->ppi_clauses,
+ child_aris);
+ new_path->parent->ppilist = lappend(new_path->parent->ppilist, new_ppi);
+ }
+ else
+ bms_free(required_outer);
+
+ new_path->param_info = new_ppi;
+
+ /*
+ * Adjust the path target if the parent of the outer relation is referenced
+ * in the targetlist. This can happen when only the parent of outer relation is
+ * laterally referenced in this relation.
+ */
+ if (bms_overlap(path->parent->lateral_relids, child_rel->top_parent_relids))
+ {
+ MemoryContext old_context;
+
+ /*
+ * Allocate the target in planner's context, since they are copies as
+ * is from path while creating plans.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ MemoryContextSwitchTo(old_context);
+ }
+
+ /*
+ * Change parameterization of subpaths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_by_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_by_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = build_child_clauses(root,
+ jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_by_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexclauses = build_child_clauses(root, ipath->indexclauses,
+ child_aris);
+ ipath->indexquals = build_child_clauses(root, ipath->indexquals,
+ child_aris);
+ }
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 1eed987..46eea02 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -53,8 +53,6 @@ static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
static void set_foreign_rel_properties(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
-extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
- Relids required_outer);
static void build_joinrel_partition_info(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel,
JoinType jointype);
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 81d637a..b9f5b11 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -236,6 +236,8 @@ extern PartitionJoinPath *create_partition_join_path(PlannerInfo *root,
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
@@ -277,5 +279,7 @@ extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
RelOptInfo *outer_rel, RelOptInfo *inner_rel,
RelOptInfo *parent_joinrel, JoinType jointype);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index 5832130..0347b37 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -65,5 +65,6 @@ extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
extern SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
SpecialJoinInfo *parent_sjinfo,
Relids left_relids, Relids right_relids);
+extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
#endif /* PREP_H */
--
1.7.9.5
0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patchapplication/octet-stream; name=0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patchDownload
From 59f12da00e6878169559def32adf896e38a00aa4 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 8 Feb 2017 14:42:15 +0530
Subject: [PATCH 11/11] Use IS_JOIN_REL() instead of RELOPT_JOINREL
FDW code uses RELOPT_JOINREL to check whether a given relation is a join or
not. Partition-wise joins create child-join relations, which are marked as
RELOPT_OTHER_JOINREL. Macro IS_JOIN_REL() returns true for both of those kinds,
replace RELOPT_JOINREL tests with IS_JOIN_REL() test.
Similarly replace RELOPT_OTHER_MEMBER_REL test with IS_OTHER_REL() where we
want to test for child relations of all kinds.
---
contrib/postgres_fdw/deparse.c | 10 +++++-----
contrib/postgres_fdw/postgres_fdw.c | 10 ++++++----
src/backend/foreign/foreign.c | 6 +++---
3 files changed, 14 insertions(+), 12 deletions(-)
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index d2b94aa..a2171d7 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -911,7 +911,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
* We handle relations for foreign tables, joins between those and upper
* relations.
*/
- Assert(rel->reloptkind == RELOPT_JOINREL ||
+ Assert(IS_JOIN_REL(rel) ||
rel->reloptkind == RELOPT_BASEREL ||
rel->reloptkind == RELOPT_OTHER_MEMBER_REL ||
rel->reloptkind == RELOPT_UPPER_REL);
@@ -990,7 +990,7 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
@@ -1030,7 +1030,7 @@ deparseFromExpr(List *quals, deparse_expr_cxt *context)
/* For upper relations, scanrel must be either a joinrel or a baserel */
Assert(context->foreignrel->reloptkind != RELOPT_UPPER_REL ||
- scanrel->reloptkind == RELOPT_JOINREL ||
+ IS_JOIN_REL(scanrel) ||
scanrel->reloptkind == RELOPT_BASEREL);
/* Construct FROM clause */
@@ -1178,7 +1178,7 @@ deparseLockingClause(deparse_expr_cxt *context)
appendStringInfoString(buf, " FOR UPDATE");
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(rel))
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
else
@@ -1342,7 +1342,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
RelOptInfo *rel_o = fpinfo->outerrel;
RelOptInfo *rel_i = fpinfo->innerrel;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index 5d270b9..2487f26 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -723,6 +723,8 @@ get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel)
/* If this is a child rel, we must use the topmost parent rel to search. */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->top_parent_relids;
else
relids = rel->relids;
@@ -1181,7 +1183,7 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
@@ -1247,7 +1249,7 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2527,7 +2529,7 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
@@ -2609,7 +2611,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind == RELOPT_JOINREL)
+ else if (IS_JOIN_REL(foreignrel))
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index fdb4f71..e8ca7df 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -717,7 +717,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
{
ListCell *lc;
- Assert(joinrel->reloptkind == RELOPT_JOINREL);
+ Assert(IS_JOIN_REL(joinrel));
foreach(lc, joinrel->pathlist)
{
@@ -782,7 +782,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->outerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->outerjoinpath = foreign_path->fdw_outerpath;
}
@@ -791,7 +791,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->innerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->innerjoinpath = foreign_path->fdw_outerpath;
}
--
1.7.9.5
Here is set of patches with support for partition-wise join between
multi-level partitioned tables.
On Fri, Feb 10, 2017 at 11:19 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
Fixed a problem with the way qsort was being used in the earlier set
of patches. Attached PFA the set of patches with that fixed.
This fix is included.
On Thu, Feb 9, 2017 at 4:20 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Per your suggestion I have split the patch into many smaller patches.
0001-Refactor-set_append_rel_pathlist.patch
0002-Refactor-make_join_rel.patch
0003-Refactor-adjust_appendrel_attrs.patch
0004-Refactor-build_join_rel.patch
0005-Add-function-find_param_path_info.patchThese four refactor existing code.
0006-Canonical-partition-scheme.patch
0007-Partition-wise-join-tests.patch -- just tests, they fail
0008-Partition-wise-join.patch -- actual patch implementing
partition-wise join, still some tests fail\0009-Adjust-join-related-to-code-to-accept-child-relation.patch
0010-Parameterized-path-fixes.patch
0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patch
patch to translate partition hierarchy into inheritance hierarchy
without flattening
0012-Multi-level-partitioned-table-expansion.patch
patches for multi-level partition-wise join support
0013-Multi-level-partition-wise-join-tests.patch
0014-Multi-level-partition-wise-join-support.patch
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
0001-Refactor-set_append_rel_pathlist.patchapplication/octet-stream; name=0001-Refactor-set_append_rel_pathlist.patchDownload
From cf978fcadc1985c27783c114b8a367fe795efe9e Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 14:45:37 +0530
Subject: [PATCH 01/14] Refactor set_append_rel_pathlist.
set_append_rel_pathlist() creates paths for each child relation and then
creates append paths for the "append" relation. Right now only a base relation
can have children, but with partition-wise join and aggregation a join or an
upper relation can have children as well. While the code to add paths to the
child relations differs for base, join and upper child relations, the code to
create append paths can be shared by all the three relations. Hence separating
it into a new function add_paths_to_append_rel() so that it can be re-used for
all kinds of relations.
---
src/backend/optimizer/path/allpaths.c | 51 ++++++++++++++++++++++++++-------
1 file changed, 41 insertions(+), 10 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 5c18987..d797d6a 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -127,6 +127,8 @@ static void recurse_push_qual(Node *setOp, Query *topquery,
RangeTblEntry *rte, Index rti, Node *qual);
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
static int compute_parallel_worker(RelOptInfo *rel, BlockNumber pages);
+static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels);
/*
@@ -1169,19 +1171,11 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
{
int parentRTindex = rti;
List *live_childrels = NIL;
- List *subpaths = NIL;
- bool subpaths_valid = true;
- List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
- List *all_child_pathkeys = NIL;
- List *all_child_outers = NIL;
ListCell *l;
/*
* Generate access paths for each member relation, and remember the
- * cheapest path for each one. Also, identify all pathkeys (orderings)
- * and parameterizations (required_outer sets) available for the member
- * relations.
+ * non-dummy children.
*/
foreach(l, root->append_rel_list)
{
@@ -1189,7 +1183,6 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
int childRTindex;
RangeTblEntry *childRTE;
RelOptInfo *childrel;
- ListCell *lcp;
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -1224,6 +1217,44 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* Child is live, so add it to the live_childrels list for use below.
*/
live_childrels = lappend(live_childrels, childrel);
+ }
+
+ /* Add Append/MergeAppend paths to the "append" relation. */
+ add_paths_to_append_rel(root, rel, live_childrels);
+}
+
+
+/*
+ * add_paths_to_append_rel
+ * Generate Append/MergeAppend paths for given "append" relation.
+ *
+ * The function collects all parameterizations and orderings supported by the
+ * non-dummy children. For every such parameterization or ordering, it creates
+ * an append path collecting one path from each non-dummy child with given
+ * parameterization or ordering. Similarly it collects partial paths from
+ * non-dummy children to create partial append paths.
+ */
+static void
+add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
+ List *live_childrels)
+{
+ List *subpaths = NIL;
+ bool subpaths_valid = true;
+ List *partial_subpaths = NIL;
+ bool partial_subpaths_valid = true;
+ List *all_child_pathkeys = NIL;
+ List *all_child_outers = NIL;
+ ListCell *l;
+
+ /*
+ * For every non-dummy child, remember the cheapest path. Also, identify
+ * all pathkeys (orderings) and parameterizations (required_outer sets)
+ * available for the non-dummy member relations.
+ */
+ foreach (l, live_childrels)
+ {
+ RelOptInfo *childrel = lfirst(l);
+ ListCell *lcp;
/*
* If child has an unparameterized cheapest-total path, add that to
--
1.7.9.5
0002-Refactor-make_join_rel.patchapplication/octet-stream; name=0002-Refactor-make_join_rel.patchDownload
From 80861ce9a56d639833f015392bb6d4035a9deda2 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 15:41:39 +0530
Subject: [PATCH 02/14] Refactor make_join_rel().
The code in make_join_rel() to add paths to join relation for a given pair of
joining relations can be re-used to add paths to a child join relation, which
do not need the other functionality offered by make_join_rel(). Separate this
code into populate_joinrel_with_paths(). This patch does just refactors
make_join_rel() to pave the way for partition-wise join.
---
src/backend/optimizer/path/joinrels.c | 28 ++++++++++++++++++++++++----
1 file changed, 24 insertions(+), 4 deletions(-)
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 6f3c20b..936ee0c 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -32,6 +32,9 @@ static bool is_dummy_rel(RelOptInfo *rel);
static void mark_dummy_rel(RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
+static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist);
/*
@@ -724,6 +727,27 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
return joinrel;
}
+ /* Add paths to the join relation. */
+ populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
+ restrictlist);
+
+ bms_free(joinrelids);
+
+ return joinrel;
+}
+
+/*
+ * populate_joinrel_with_paths
+ * Add paths to the given joinrel for given pair of joining relations. The
+ * SpecialJoinInfo provides details about the join and the restrictlist
+ * contains the join clauses and the other clauses applicable for given pair
+ * of the joining relations.
+ */
+static void
+populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *sjinfo, List *restrictlist)
+{
/*
* Consider paths using each rel as both outer and inner. Depending on
* the join type, a provably empty outer or inner rel might mean the join
@@ -868,10 +892,6 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
elog(ERROR, "unrecognized join type: %d", (int) sjinfo->jointype);
break;
}
-
- bms_free(joinrelids);
-
- return joinrel;
}
--
1.7.9.5
0003-Refactor-adjust_appendrel_attrs.patchapplication/octet-stream; name=0003-Refactor-adjust_appendrel_attrs.patchDownload
From 74d38c91f9c37f8c6ede2a1a63ae3fec6731a10d Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 3 Feb 2017 17:22:52 +0530
Subject: [PATCH 03/14] Refactor adjust_appendrel_attrs.
adjust_appendrel_attrs() is used to translate nodes for a parent relation to
those for a child relation by replacing the parent specific nodes like Var
nodes with corresponding nodes specific to the child. Right now this function
works with a single parent-child pair. For partition-wise join and
partition-wise aggregation/grouping, we require to translate nodes for multiple
parent-child pairs. This patch modifies adjust_appendrel_attrs() to work with
multiple parent-child pairs.
---
src/backend/optimizer/path/allpaths.c | 7 +-
src/backend/optimizer/path/equivclass.c | 2 +-
src/backend/optimizer/plan/planner.c | 2 +-
src/backend/optimizer/prep/prepunion.c | 161 ++++++++++++++++++++++---------
src/include/optimizer/prep.h | 2 +-
5 files changed, 121 insertions(+), 53 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index d797d6a..d8fac14 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -862,6 +862,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
ListCell *parentvars;
ListCell *childvars;
ListCell *lc;
+ List *appinfo_list = list_make1(appinfo);
/* append_rel_list contains all append rels; ignore others */
if (appinfo->parent_relid != parentRTindex)
@@ -903,7 +904,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Assert(IsA(rinfo, RestrictInfo));
childqual = adjust_appendrel_attrs(root,
(Node *) rinfo->clause,
- appinfo);
+ appinfo_list);
childqual = eval_const_expressions(root, childqual);
/* check for flat-out constant */
if (childqual && IsA(childqual, Const))
@@ -1022,11 +1023,11 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->joininfo = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->joininfo,
- appinfo);
+ appinfo_list);
childrel->reltarget->exprs = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->reltarget->exprs,
- appinfo);
+ appinfo_list);
/*
* We have to make child entries in the EquivalenceClass data
diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c
index a329dd1..bcce142 100644
--- a/src/backend/optimizer/path/equivclass.c
+++ b/src/backend/optimizer/path/equivclass.c
@@ -2111,7 +2111,7 @@ add_child_rel_equivalences(PlannerInfo *root,
child_expr = (Expr *)
adjust_appendrel_attrs(root,
(Node *) cur_em->em_expr,
- appinfo);
+ list_make1(appinfo));
/*
* Transform em_relids to match. Note we do *not* do
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 881742f..24a48b8 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -1085,7 +1085,7 @@ inheritance_planner(PlannerInfo *root)
subroot->parse = (Query *)
adjust_appendrel_attrs(root,
(Node *) parse,
- appinfo);
+ list_make1(appinfo));
/*
* If there are securityQuals attached to the parent, move them to the
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 06e843d..6f41979 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -55,7 +55,7 @@
typedef struct
{
PlannerInfo *root;
- AppendRelInfo *appinfo;
+ List *appinfos;
} adjust_appendrel_attrs_context;
static Path *recurse_set_operations(Node *setOp, PlannerInfo *root,
@@ -107,9 +107,9 @@ static Bitmapset *translate_col_privs(const Bitmapset *parent_privs,
List *translated_vars);
static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
-static Relids adjust_relid_set(Relids relids, Index oldrelid, Index newrelid);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
+static Relids adjust_relid_set(Relids relids, List *append_rel_infos);
/*
@@ -1719,10 +1719,10 @@ translate_col_privs(const Bitmapset *parent_privs,
/*
* adjust_appendrel_attrs
- * Copy the specified query or expression and translate Vars referring
- * to the parent rel of the specified AppendRelInfo to refer to the
- * child rel instead. We also update rtindexes appearing outside Vars,
- * such as resultRelation and jointree relids.
+ * Copy the specified query or expression and translate Vars referring to
+ * the parent rels of the specified in the given list of AppendRelInfos to
+ * refer to the corresponding child rel instead. We also update rtindexes
+ * appearing outside Vars, such as resultRelation and jointree relids.
*
* Note: this is only applied after conversion of sublinks to subplans,
* so we don't need to cope with recursion into sub-queries.
@@ -1731,13 +1731,20 @@ translate_col_privs(const Bitmapset *parent_privs,
* maybe we should try to fold the two routines together.
*/
Node *
-adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
+adjust_appendrel_attrs(PlannerInfo *root, Node *node, List *appinfos)
{
Node *result;
adjust_appendrel_attrs_context context;
+ ListCell *lc;
context.root = root;
- context.appinfo = appinfo;
+ context.appinfos = appinfos;
+
+ /*
+ * Catch a caller who wants to adjust expressions, but doesn't pass any
+ * AppendRelInfo.
+ */
+ Assert(appinfos && list_length(appinfos) >= 1);
/*
* Must be prepared to start with a Query or a bare expression tree.
@@ -1745,20 +1752,28 @@ adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo)
if (node && IsA(node, Query))
{
Query *newnode;
+ AppendRelInfo *appinfo;
newnode = query_tree_mutator((Query *) node,
adjust_appendrel_attrs_mutator,
(void *) &context,
QTW_IGNORE_RC_SUBQUERIES);
- if (newnode->resultRelation == appinfo->parent_relid)
+ foreach (lc, appinfos)
{
- newnode->resultRelation = appinfo->child_relid;
- /* Fix tlist resnos too, if it's inherited UPDATE */
- if (newnode->commandType == CMD_UPDATE)
- newnode->targetList =
- adjust_inherited_tlist(newnode->targetList,
- appinfo);
+ appinfo = lfirst(lc);
+
+ if (newnode->resultRelation == appinfo->parent_relid)
+ {
+ newnode->resultRelation = appinfo->child_relid;
+ /* Fix tlist resnos too, if it's inherited UPDATE */
+ if (newnode->commandType == CMD_UPDATE)
+ newnode->targetList =
+ adjust_inherited_tlist(newnode->targetList,
+ appinfo);
+ break;
+ }
}
+
result = (Node *) newnode;
}
else
@@ -1771,13 +1786,29 @@ static Node *
adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context)
{
- AppendRelInfo *appinfo = context->appinfo;
+ List *appinfos = context->appinfos;
+ ListCell *lc;
+
+ /*
+ * Catch a caller who wants to adjust expressions, but doesn't pass any
+ * AppendRelInfo.
+ */
+ Assert(appinfos && list_length(appinfos) >= 1);
if (node == NULL)
return NULL;
if (IsA(node, Var))
{
Var *var = (Var *) copyObject(node);
+ AppendRelInfo *appinfo;
+
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (var->varno == appinfo->parent_relid)
+ break;
+ }
if (var->varlevelsup == 0 &&
var->varno == appinfo->parent_relid)
@@ -1860,29 +1891,54 @@ adjust_appendrel_attrs_mutator(Node *node,
{
CurrentOfExpr *cexpr = (CurrentOfExpr *) copyObject(node);
- if (cexpr->cvarno == appinfo->parent_relid)
- cexpr->cvarno = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (cexpr->cvarno == appinfo->parent_relid)
+ {
+ cexpr->cvarno = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) cexpr;
}
if (IsA(node, RangeTblRef))
{
RangeTblRef *rtr = (RangeTblRef *) copyObject(node);
- if (rtr->rtindex == appinfo->parent_relid)
- rtr->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (rtr->rtindex == appinfo->parent_relid)
+ {
+ rtr->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) rtr;
}
if (IsA(node, JoinExpr))
{
/* Copy the JoinExpr node with correct mutation of subnodes */
JoinExpr *j;
+ AppendRelInfo *appinfo;
j = (JoinExpr *) expression_tree_mutator(node,
adjust_appendrel_attrs_mutator,
(void *) context);
/* now fix JoinExpr's rtindex (probably never happens) */
- if (j->rtindex == appinfo->parent_relid)
- j->rtindex = appinfo->child_relid;
+ foreach (lc, appinfos)
+ {
+ appinfo = lfirst(lc);
+
+ if (j->rtindex == appinfo->parent_relid)
+ {
+ j->rtindex = appinfo->child_relid;
+ break;
+ }
+ }
return (Node *) j;
}
if (IsA(node, PlaceHolderVar))
@@ -1895,9 +1951,7 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == 0)
- phv->phrels = adjust_relid_set(phv->phrels,
- appinfo->parent_relid,
- appinfo->child_relid);
+ phv->phrels = adjust_relid_set(phv->phrels, context->appinfos);
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1929,23 +1983,17 @@ adjust_appendrel_attrs_mutator(Node *node,
/* adjust relid sets too */
newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
- appinfo->parent_relid,
- appinfo->child_relid);
+ context->appinfos);
/*
* Reset cached derivative fields, since these might need to have
@@ -1977,19 +2025,38 @@ adjust_appendrel_attrs_mutator(Node *node,
}
/*
- * Substitute newrelid for oldrelid in a Relid set
+ * Replace parent relids by child relids in the copy of given relid set
+ * according to the given list of AppendRelInfos. The given relid set is
+ * returned as is if it contains no parent in the given list, otherwise, the
+ * given relid set is not changed.
*/
-static Relids
-adjust_relid_set(Relids relids, Index oldrelid, Index newrelid)
+Relids
+adjust_relid_set(Relids relids, List *append_rel_infos)
{
- if (bms_is_member(oldrelid, relids))
+ ListCell *lc;
+ Bitmapset *result = NULL;
+
+ foreach (lc, append_rel_infos)
{
- /* Ensure we have a modifiable copy */
- relids = bms_copy(relids);
- /* Remove old, add new */
- relids = bms_del_member(relids, oldrelid);
- relids = bms_add_member(relids, newrelid);
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ /* Remove parent, add child */
+ if (bms_is_member(appinfo->parent_relid, relids))
+ {
+ /* Make a copy if we are changing the set. */
+ if (!result)
+ result = bms_copy(relids);
+
+ result = bms_del_member(result, appinfo->parent_relid);
+ result = bms_add_member(result, appinfo->child_relid);
+ }
}
+
+ /* Return new set if we modified the given set. */
+ if (result)
+ return result;
+
+ /* Else return the given relids set as is. */
return relids;
}
@@ -2110,5 +2177,5 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
else
Assert(parent_rel->reloptkind == RELOPT_BASEREL);
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, appinfo);
+ return adjust_appendrel_attrs(root, node, list_make1(appinfo));
}
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index 2b20b36..a02e06a 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -53,7 +53,7 @@ extern RelOptInfo *plan_set_operations(PlannerInfo *root);
extern void expand_inherited_tables(PlannerInfo *root);
extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
- AppendRelInfo *appinfo);
+ List *appinfos);
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
--
1.7.9.5
0004-Refactor-build_join_rel.patchapplication/octet-stream; name=0004-Refactor-build_join_rel.patchDownload
From 5606e2526b997606e8485c00fc34ac1f5ccf2fe9 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Mon, 6 Feb 2017 10:58:48 +0530
Subject: [PATCH 04/14] Refactor build_join_rel.
Partition-wise joins do not use build_join_rel() to build child-join relations,
but it still requires code to set foreign relation properties as well as code
to add join relation into PlannerInfo. Separate that code into
set_foreign_rel_properties() and add_join_rel() resp. to be called while
building child joins.
---
src/backend/optimizer/util/relnode.c | 142 ++++++++++++++++++++--------------
1 file changed, 83 insertions(+), 59 deletions(-)
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index adc1db9..160ed6d 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -49,6 +49,9 @@ static List *subbuild_joinrel_restrictlist(RelOptInfo *joinrel,
static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
List *joininfo_list,
List *new_joininfo);
+static void set_foreign_rel_properties(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
/*
@@ -327,6 +330,82 @@ find_join_rel(PlannerInfo *root, Relids relids)
}
/*
+ * set_foreign_rel_properties
+ * Set up foreign-join fields if outer and inner relation are foreign
+ * tables (or joins) belonging to the same server and assigned to the same
+ * user to check access permissions as.
+ *
+ * In addition to an exact match of userid, we allow the case where one side
+ * has zero userid (implying current user) and the other side has explicit
+ * userid that happens to equal the current user; but in that case, pushdown of
+ * the join is only valid for the current user. The useridiscurrent field
+ * records whether we had to make such an assumption for this join or any
+ * sub-join.
+ *
+ * Otherwise these fields are left invalid, so GetForeignJoinPaths will not be
+ * called for the join relation.
+ *
+ */
+static void
+set_foreign_rel_properties(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel)
+{
+ if (OidIsValid(outer_rel->serverid) &&
+ inner_rel->serverid == outer_rel->serverid)
+ {
+ if (inner_rel->userid == outer_rel->userid)
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(inner_rel->userid) &&
+ outer_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = outer_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ else if (!OidIsValid(outer_rel->userid) &&
+ inner_rel->userid == GetUserId())
+ {
+ joinrel->serverid = outer_rel->serverid;
+ joinrel->userid = inner_rel->userid;
+ joinrel->useridiscurrent = true;
+ joinrel->fdwroutine = outer_rel->fdwroutine;
+ }
+ }
+}
+
+/*
+ * add_join_rel
+ * Add given join relation to the list of join relations in the given
+ * PlannerInfo. Also add it to the auxiliary hashtable if there is one.
+ */
+void
+add_join_rel(PlannerInfo *root, RelOptInfo *joinrel)
+{
+ /* GEQO requires us to append the new joinrel to the end of the list! */
+ root->join_rel_list = lappend(root->join_rel_list, joinrel);
+
+ /* store it into the auxiliary hashtable if there is one. */
+ if (root->join_rel_hash)
+ {
+ JoinHashEntry *hentry;
+ bool found;
+
+ hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
+ &(joinrel->relids),
+ HASH_ENTER,
+ &found);
+ Assert(!found);
+ hentry->join_rel = joinrel;
+ }
+}
+
+/*
* build_join_rel
* Returns relation entry corresponding to the union of two given rels,
* creating a new relation entry if none already exists.
@@ -424,46 +503,8 @@ build_join_rel(PlannerInfo *root,
joinrel->joininfo = NIL;
joinrel->has_eclass_joins = false;
- /*
- * Set up foreign-join fields if outer and inner relation are foreign
- * tables (or joins) belonging to the same server and assigned to the same
- * user to check access permissions as. In addition to an exact match of
- * userid, we allow the case where one side has zero userid (implying
- * current user) and the other side has explicit userid that happens to
- * equal the current user; but in that case, pushdown of the join is only
- * valid for the current user. The useridiscurrent field records whether
- * we had to make such an assumption for this join or any sub-join.
- *
- * Otherwise these fields are left invalid, so GetForeignJoinPaths will
- * not be called for the join relation.
- */
- if (OidIsValid(outer_rel->serverid) &&
- inner_rel->serverid == outer_rel->serverid)
- {
- if (inner_rel->userid == outer_rel->userid)
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = outer_rel->useridiscurrent || inner_rel->useridiscurrent;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(inner_rel->userid) &&
- outer_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = outer_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- else if (!OidIsValid(outer_rel->userid) &&
- inner_rel->userid == GetUserId())
- {
- joinrel->serverid = outer_rel->serverid;
- joinrel->userid = inner_rel->userid;
- joinrel->useridiscurrent = true;
- joinrel->fdwroutine = outer_rel->fdwroutine;
- }
- }
+ /* Compute information relevant to the foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
/*
* Create a new tlist containing just the vars that need to be output from
@@ -531,25 +572,8 @@ build_join_rel(PlannerInfo *root,
is_parallel_safe(root, (Node *) joinrel->reltarget->exprs))
joinrel->consider_parallel = true;
- /*
- * Add the joinrel to the query's joinrel list, and store it into the
- * auxiliary hashtable if there is one. NB: GEQO requires us to append
- * the new joinrel to the end of the list!
- */
- root->join_rel_list = lappend(root->join_rel_list, joinrel);
-
- if (root->join_rel_hash)
- {
- JoinHashEntry *hentry;
- bool found;
-
- hentry = (JoinHashEntry *) hash_search(root->join_rel_hash,
- &(joinrel->relids),
- HASH_ENTER,
- &found);
- Assert(!found);
- hentry->join_rel = joinrel;
- }
+ /* Add the joinrel to the PlannerInfo. */
+ add_join_rel(root, joinrel);
/*
* Also, if dynamic-programming join search is active, add the new joinrel
--
1.7.9.5
0005-Add-function-find_param_path_info.patchapplication/octet-stream; name=0005-Add-function-find_param_path_info.patchDownload
From ec2984ab4ea387d5e91fbd354209ff45f114b603 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Mon, 6 Feb 2017 12:14:06 +0530
Subject: [PATCH 05/14] Add function find_param_path_info.
The code to search ParamPathInfo for a set of required outer relations in the
list of ParamPathInfos of a given relation is duplicated in
get_*rel_parampathinfo() functions. Separate this code into
find_param_path_info() and call it from get_*rel_parampathinfo() functions.
---
src/backend/optimizer/util/relnode.c | 46 ++++++++++++++++++++--------------
1 file changed, 27 insertions(+), 19 deletions(-)
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 160ed6d..19982dc 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -52,6 +52,8 @@ static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
static void set_foreign_rel_properties(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
/*
@@ -1047,12 +1049,8 @@ get_baserel_parampathinfo(PlannerInfo *root, RelOptInfo *baserel,
Assert(!bms_overlap(baserel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, baserel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(baserel, required_outer)))
+ return ppi;
/*
* Identify all joinclauses that are movable to this base rel given this
@@ -1289,12 +1287,8 @@ get_joinrel_parampathinfo(PlannerInfo *root, RelOptInfo *joinrel,
*restrict_clauses = list_concat(pclauses, *restrict_clauses);
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, joinrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(joinrel, required_outer)))
+ return ppi;
/* Estimate the number of rows returned by the parameterized join */
rows = get_parameterized_joinrel_size(root, joinrel,
@@ -1333,7 +1327,6 @@ ParamPathInfo *
get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
{
ParamPathInfo *ppi;
- ListCell *lc;
/* Unparameterized paths have no ParamPathInfo */
if (bms_is_empty(required_outer))
@@ -1342,12 +1335,8 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
Assert(!bms_overlap(appendrel->relids, required_outer));
/* If we already have a PPI for this parameterization, just return it */
- foreach(lc, appendrel->ppilist)
- {
- ppi = (ParamPathInfo *) lfirst(lc);
- if (bms_equal(ppi->ppi_req_outer, required_outer))
- return ppi;
- }
+ if ((ppi = find_param_path_info(appendrel, required_outer)))
+ return ppi;
/* Else build the ParamPathInfo */
ppi = makeNode(ParamPathInfo);
@@ -1358,3 +1347,22 @@ get_appendrel_parampathinfo(RelOptInfo *appendrel, Relids required_outer)
return ppi;
}
+
+/*
+ * Returns a ParamPathInfo for outer relations specified by required_outer, if
+ * already available in the given rel. Returns NULL otherwise.
+ */
+ParamPathInfo *
+find_param_path_info(RelOptInfo *rel, Relids required_outer)
+{
+ ListCell *lc;
+
+ foreach(lc, rel->ppilist)
+ {
+ ParamPathInfo *ppi = (ParamPathInfo *) lfirst(lc);
+ if (bms_equal(ppi->ppi_req_outer, required_outer))
+ return ppi;
+ }
+
+ return NULL;
+}
--
1.7.9.5
0006-Canonical-partition-scheme.patchapplication/octet-stream; name=0006-Canonical-partition-scheme.patchDownload
From 53c7c239715824278c2abe19c15abdb1ed3d7d91 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 10:47:49 +0530
Subject: [PATCH 06/14] Canonical partition scheme.
For a single level partitioned table, annotate RelOptInfo of a partitioned
table with canonical partition scheme. All partitioned tables, with the same
partitioning scheme share the same canonical partitioning scheme. We store the
RelOptInfo's corresponding to the partitions in RelOptInfo of the partitioned
table. Those are arranged in the same order as the partition bound indices in
the partition scheme.
We do not handle multi-level partitioned tables since inheritance hierarchy
does not retain the partition hierarchy. All the partitions at any level
appear as children of the top-level partitioned table. Thus making it hard to
associate a partition relation with corresponding partition bounds.
Multi-level partitioned tables will be handled in a separate patch.
---
src/backend/optimizer/path/allpaths.c | 48 +++++++
src/backend/optimizer/util/plancat.c | 232 +++++++++++++++++++++++++++++++++
src/include/nodes/relation.h | 51 ++++++++
3 files changed, 331 insertions(+)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index d8fac14..0eb56f3 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -829,6 +829,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
double *parent_attrsizes;
int nattrs;
ListCell *l;
+ int nparts;
/*
* Initialize to compute size estimates for whole append relation.
@@ -850,6 +851,18 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
nattrs = rel->max_attr - rel->min_attr + 1;
parent_attrsizes = (double *) palloc0(nattrs * sizeof(double));
+ /*
+ * For a partitioned table, allocate an array to hold RelOptInfo's of the
+ * partitions. It will be filled while handling the children below.
+ */
+ if (rel->part_scheme)
+ {
+ nparts = rel->part_scheme->nparts;
+ rel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+ }
+ else
+ nparts = 0;
+
foreach(l, root->append_rel_list)
{
AppendRelInfo *appinfo = (AppendRelInfo *) lfirst(l);
@@ -879,6 +892,30 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
/*
+ * Two partitioned tables with the same partitioning scheme, have their
+ * partition bounds arranged in the same order. The order of partition
+ * OIDs in RelOptInfo corresponds to the partition bound order. Thus
+ * the OIDs of matching partitions from both the tables are placed at
+ * the same position in the array of partition OIDs in the respective
+ * RelOptInfos. Arranging RelOptInfos of partitions in the same order
+ * as their OIDs makes it easy to find the RelOptInfos of matching
+ * partitions for partition-wise join.
+ */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (rel->part_oids[cnt_parts] == childRTE->relid)
+ {
+ Assert(!rel->part_rels[cnt_parts]);
+ rel->part_rels[cnt_parts] = childrel;
+ }
+ }
+ }
+
+ /*
* We have to copy the parent's targetlist and quals to the child,
* with appropriate substitution of variables. However, only the
* baserestrictinfo quals are needed before we can check for
@@ -1130,6 +1167,17 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
}
+ /* Should have found all the childrels of a partitioned relation. */
+ if (rel->part_scheme)
+ {
+ int cnt_parts;
+
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ if (!rel->part_rels[cnt_parts])
+ elog(ERROR, "could not find the RelOptInfo of a partition with oid %u",
+ rel->part_oids[cnt_parts]);
+ }
+
if (has_live_children)
{
/*
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 7836e6b..01ba885 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -27,6 +27,7 @@
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/heap.h"
+#include "catalog/pg_inherits_fn.h"
#include "catalog/partition.h"
#include "catalog/pg_am.h"
#include "foreign/fdwapi.h"
@@ -63,6 +64,13 @@ static List *get_relation_constraints(PlannerInfo *root,
bool include_notnull);
static List *build_index_tlist(PlannerInfo *root, IndexOptInfo *index,
Relation heapRelation);
+static List **build_baserel_partition_key_exprs(Relation relation,
+ Index varno);
+static PartitionScheme find_partition_scheme(struct PlannerInfo *root,
+ Relation rel);
+static void get_relation_partition_info(PlannerInfo *root, RelOptInfo *rel,
+ Relation relation, bool inhparent);
+
/*
@@ -412,6 +420,9 @@ get_relation_info(PlannerInfo *root, Oid relationObjectId, bool inhparent,
/* Collect info about relation's foreign keys, if relevant */
get_relation_foreign_keys(root, rel, relation, inhparent);
+ /* Collect info about relation's partitioning scheme, if any. */
+ get_relation_partition_info(root, rel, relation, inhparent);
+
heap_close(relation, NoLock);
/*
@@ -1716,3 +1727,224 @@ has_row_triggers(PlannerInfo *root, Index rti, CmdType event)
heap_close(relation, NoLock);
return result;
}
+
+/*
+ * get_relation_partition_info
+ *
+ * Retrieves partitioning information for a given relation.
+ *
+ * Partitioning scheme, partition key expressions and OIDs of partitions are
+ * added to the given RelOptInfo. A partitioned table can participate in the
+ * query as a simple relation or an inheritance parent. Only the later can have
+ * child relations, and hence partitions. From the point of view of the query
+ * optimizer only such relations are considered to be partitioned. Hence
+ * partitioning information is set only for an inheritance parent.
+ */
+static void
+get_relation_partition_info(PlannerInfo *root, RelOptInfo *rel,
+ Relation relation, bool inhparent)
+{
+ /* No partitioning information for an unpartitioned relation. */
+ if (relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE ||
+ !inhparent ||
+ !(rel->part_scheme = find_partition_scheme(root, relation)))
+ {
+ rel->partexprs = NULL;
+ rel->part_rels = NULL;
+ rel->part_oids = NULL;
+ return;
+ }
+
+ rel->partexprs = build_baserel_partition_key_exprs(relation, rel->relid);
+ rel->part_oids = RelationGetPartitionDesc(relation)->oids;
+
+ /*
+ * RelOptInfos of the partitions will be filled in when we build those for
+ * the child relations.
+ */
+ rel->part_rels = NULL;
+ return;
+}
+
+/*
+ * find_partition_scheme
+ *
+ * The function returns a canonical partition scheme which exactly matches the
+ * partitioning properties of the given relation if one exists in the of
+ * canonical partitioning schemes maintained in PlannerInfo. If none of the
+ * existing partitioning schemes match, the function creates a canonical
+ * partition scheme and adds it to the list.
+ *
+ * For an unpartitioned table or for a multi-level partitioned table it returns
+ * NULL. See comments in the function for more details.
+ */
+static PartitionScheme
+find_partition_scheme(PlannerInfo *root, Relation relation)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ PartitionDesc part_desc = RelationGetPartitionDesc(relation);
+ ListCell *lc;
+ int nparts;
+ int partnatts;
+ int cnt_pks;
+ int cnt_parts;
+ PartitionScheme part_scheme = NULL;
+
+ /* No partition scheme for an unpartitioned relation. */
+ if (!part_desc || !part_key)
+ return NULL;
+
+ nparts = part_desc->nparts;
+ partnatts = part_key->partnatts;
+
+ /*
+ * For a multi-level partitioned table, we do not retain the partitioning
+ * hierarchy while expanding RTE for the topmost parent. Thus the number of
+ * children as per root->append_rel_list does not match the number of
+ * partitions specified in the partition descriptor and hence the
+ * partitioning scheme of a multi-partitioned table does not reflect the
+ * true picture. So for now, treat a multi-partitioned table as not
+ * partitioned.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ if (has_subclass(part_desc->oids[cnt_parts]))
+ return NULL;
+ }
+
+ /* Search for a matching partition scheme and return if found one. */
+ foreach (lc, root->part_schemes)
+ {
+ part_scheme = lfirst(lc);
+
+ /* Match number of partitions and partitioning strategy. */
+ if (nparts != part_scheme->nparts ||
+ part_key->strategy != part_scheme->strategy ||
+ partnatts != part_scheme->partnatts)
+ continue;
+
+ /* Match the partition key types. */
+ for (cnt_pks = 0; cnt_pks < partnatts; cnt_pks++)
+ {
+ /*
+ * For types, it suffices to match the type id, mod and collation;
+ * len, byval and align are depedent on the first two.
+ */
+ if (part_key->partopfamily[cnt_pks] != part_scheme->partopfamily[cnt_pks] ||
+ part_key->partopcintype[cnt_pks] != part_scheme->partopcintype[cnt_pks] ||
+ part_key->parttypid[cnt_pks] != part_scheme->key_types[cnt_pks] ||
+ part_key->parttypmod[cnt_pks] != part_scheme->key_typmods[cnt_pks] ||
+ part_key->parttypcoll[cnt_pks] != part_scheme->key_collations[cnt_pks])
+ break;
+ }
+
+ /* Some partition key didn't match. Check next partitioning scheme. */
+ if (cnt_pks < partnatts)
+ continue;
+
+ if (!partition_bounds_equal(part_key, part_desc->boundinfo,
+ part_scheme->boundinfo))
+ continue;
+
+ /* Found matching partition scheme. */
+ return part_scheme;
+ }
+
+ /* Did not find matching partition scheme. Create one. */
+ part_scheme = (PartitionScheme) palloc0(sizeof(PartitionSchemeData));
+
+ /* Copy partition bounds/lists. */
+ part_scheme->nparts = part_desc->nparts;
+ part_scheme->strategy = part_key->strategy;
+ part_scheme->boundinfo = part_desc->boundinfo;
+
+ /* Store partition key information. */
+ part_scheme->partnatts = part_key->partnatts;
+
+ part_scheme->partopfamily = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopfamily, part_key->partopfamily,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->partopcintype = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->partopcintype, part_key->partopcintype,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_types = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_types, part_key->parttypid,
+ sizeof(Oid) * partnatts);
+
+ part_scheme->key_typmods = (int32 *) palloc(sizeof(int32) * partnatts);
+ memcpy(part_scheme->key_typmods, part_key->parttypmod,
+ sizeof(int32) * partnatts);
+
+ part_scheme->key_collations = (Oid *) palloc(sizeof(Oid) * partnatts);
+ memcpy(part_scheme->key_collations, part_key->parttypcoll,
+ sizeof(Oid) * partnatts);
+
+ /* Add the partitioning scheme to PlannerInfo. */
+ root->part_schemes = lappend(root->part_schemes, part_scheme);
+
+ return part_scheme;
+}
+
+/*
+ * build_baserel_partition_key_exprs
+ *
+ * Collect partition key expressions for a given base relation. The function
+ * converts any single column partition keys into corresponding Var nodes. It
+ * restamps Var nodes in partition key expressions by given varno. The
+ * partition key expressions are returned as an array of single element Lists
+ * to be stored in RelOptInfo of the base relation.
+ */
+static List **
+build_baserel_partition_key_exprs(Relation relation, Index varno)
+{
+ PartitionKey part_key = RelationGetPartitionKey(relation);
+ int num_pkexprs;
+ int cnt_pke;
+ List **partexprs;
+ ListCell *lc;
+
+ if (!part_key || part_key->partnatts <= 0)
+ return NULL;
+
+ num_pkexprs = part_key->partnatts;
+ partexprs = (List **) palloc(sizeof(List *) * num_pkexprs);
+ lc = list_head(part_key->partexprs);
+
+ for (cnt_pke = 0; cnt_pke < num_pkexprs; cnt_pke++)
+ {
+ AttrNumber attno = part_key->partattrs[cnt_pke];
+ Expr *pkexpr;
+
+ if (attno != InvalidAttrNumber)
+ {
+ /* Single column partition key is stored as a Var node. */
+ Form_pg_attribute att_tup;
+
+ if (attno < 0)
+ att_tup = SystemAttributeDefinition(attno,
+ relation->rd_rel->relhasoids);
+ else
+ att_tup = relation->rd_att->attrs[attno - 1];
+
+ pkexpr = (Expr *) makeVar(varno, attno, att_tup->atttypid,
+ att_tup->atttypmod,
+ att_tup->attcollation, 0);
+ }
+ else
+ {
+ if (lc == NULL)
+ elog(ERROR, "wrong number of partition key expressions");
+
+ /* Re-stamp the expressions with given varno. */
+ pkexpr = (Expr *) copyObject(lfirst(lc));
+ ChangeVarNodes((Node *) pkexpr, 1, varno, 0);
+ lc = lnext(lc);
+ }
+
+ partexprs[cnt_pke] = list_make1(pkexpr);
+ }
+
+ return partexprs;
+}
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 643be54..4f99184 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -15,6 +15,7 @@
#define RELATION_H
#include "access/sdir.h"
+#include "catalog/partition.h"
#include "lib/stringinfo.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
@@ -261,6 +262,9 @@ typedef struct PlannerInfo
List *distinct_pathkeys; /* distinctClause pathkeys, if any */
List *sort_pathkeys; /* sortClause pathkeys, if any */
+ List *part_schemes; /* Canonicalised partition schemes
+ * used in the query. */
+
List *initial_rels; /* RelOptInfos we are now trying to join */
/* Use fetch_upper_rel() to get any particular upper rel */
@@ -321,6 +325,38 @@ typedef struct PlannerInfo
((root)->simple_rte_array ? (root)->simple_rte_array[rti] : \
rt_fetch(rti, (root)->parse->rtable))
+/*
+ * Partitioning scheme
+ * Structure to hold partitioning scheme for a given relation.
+ *
+ * Multiple relations may be partitioned in the same way. The relations
+ * resulting from joining such relations may be partitioned in the same way as
+ * the joining relations. Similarly, relations derived from such relations by
+ * grouping, sorting may be partitioned in the same way as the underlying
+ * scan relations. All such relations partitioned in the same way share the
+ * partitioning scheme.
+ *
+ * PlannerInfo stores a list of distinct "canonical" partitioning schemes.
+ * RelOptInfo of a partitioned relation holds the pointer to "canonical"
+ * partitioning scheme.
+ */
+typedef struct PartitionSchemeData
+{
+ /* Information about partitions */
+ int nparts; /* number of partitions */
+ PartitionBoundInfo boundinfo; /* Partition bounds/lists */
+
+ /* Information about partition keys */
+ char strategy; /* partition strategy */
+ int16 partnatts; /* number of partition attributes */
+ Oid *partopfamily; /* OIDs of operator families */
+ Oid *partopcintype; /* OIDs of opclass declared input data types */
+ Oid *key_types; /* OIDs of partition key data types. */
+ int32 *key_typmods; /* typmods of partition keys. */
+ Oid *key_collations; /* OIDs of collations of partition keys. */
+} PartitionSchemeData;
+
+typedef struct PartitionSchemeData *PartitionScheme;
/*----------
* RelOptInfo
@@ -531,6 +567,7 @@ typedef struct RelOptInfo
PlannerInfo *subroot; /* if subquery */
List *subplan_params; /* if subquery */
int rel_parallel_workers; /* wanted number of parallel workers */
+ Oid *part_oids; /* OIDs of partitions */
/* Information about foreign tables and foreign joins */
Oid serverid; /* identifies server for the table or join */
@@ -549,6 +586,20 @@ typedef struct RelOptInfo
List *joininfo; /* RestrictInfo structures for join clauses
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
+
+ /* For all the partitioned relations. */
+ PartitionScheme part_scheme; /* Partitioning scheme. */
+ struct RelOptInfo **part_rels; /* Array of RelOptInfos of partitions,
+ * stored in the same order as bounds
+ * or lists in PartitionScheme.
+ */
+ List **partexprs; /* Array of list of partition key
+ * expressions. For base relations
+ * these are one element lists. For
+ * join there may be as many elements
+ * as the number of joining
+ * relations.
+ */
} RelOptInfo;
/*
--
1.7.9.5
0007-Partition-wise-join-tests.patchapplication/octet-stream; name=0007-Partition-wise-join-tests.patchDownload
From 82e4452ff549ede9f34684d363f66291a3bb632b Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 11:57:30 +0530
Subject: [PATCH 07/14] Partition-wise join tests.
This file does not contain tests for joins between multi-leveled partitioned
tables. Those will be added later.
---
src/test/regress/expected/partition_join.out | 4114 ++++++++++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/serial_schedule | 1 +
src/test/regress/sql/partition_join.sql | 515 ++++
4 files changed, 4631 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/partition_join.out
create mode 100644 src/test/regress/sql/partition_join.sql
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
new file mode 100644
index 0000000..18238fa
--- /dev/null
+++ b/src/test/regress/expected/partition_join.out
@@ -0,0 +1,4114 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ Filter: (((50) = prt1_p1.b) OR ((75) = prt2_p1.b))
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, prt1_p1.b, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ Filter: (((50) = prt1_p2.b) OR ((75) = prt2_p2.b))
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, prt1_p2.b, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ Filter: (((50) = prt1_p3.b) OR ((75) = prt2_p3.b))
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, prt1_p3.b, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+(40 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+----+------+----+------
+ 50 | 0050 | |
+ | | 75 | 0075
+(2 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ Sort Key: prt1_p1.a, prt2_p1.b
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, (25), prt2_p1.b, prt2_p1.c, (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (25), (50)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c, 25
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c, (50)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c, 50
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, (25), (50)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c, 25
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c, (50)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c, 50
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, (25), (50)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c, 25
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c, (50)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c, 50
+ Filter: ((prt2_p3.b % 25) = 0)
+(39 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | c | phv | b | c | phv
+-----+------+-----+-----+------+-----
+ 0 | 0000 | 25 | 0 | 0000 | 50
+ 50 | 0050 | 25 | | |
+ 100 | 0100 | 25 | | |
+ 150 | 0150 | 25 | 150 | 0150 | 50
+ 200 | 0200 | 25 | | |
+ 250 | 0250 | 25 | | |
+ 300 | 0300 | 25 | 300 | 0300 | 50
+ 350 | 0350 | 25 | | |
+ 400 | 0400 | 25 | | |
+ 450 | 0450 | 25 | 450 | 0450 | 50
+ 500 | 0500 | 25 | | |
+ 550 | 0550 | 25 | | |
+ | | | 75 | 0075 | 50
+ | | | 225 | 0225 | 50
+ | | | 375 | 0375 | 50
+ | | | 525 | 0525 | 50
+(16 rows)
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p2 t2
+ Output: t2.b, t2.c
+ Filter: (t2.b > 250)
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p2 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a < 450) AND ((t1.a % 25) = 0))
+(15 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Nested Loop Left Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Join Filter: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Right Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt2_p2.b = prt1_p2.a)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: (prt2_p2.b > 250)
+ -> Hash
+ Output: prt1_p2.a, prt1_p2.c
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+(24 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Sort Key: prt1_p2.a, prt2_p2.b
+ -> Result
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ -> Append
+ -> Hash Right Join
+ Output: prt2_p2.b, prt2_p2.c, prt1_p2.a, prt1_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: (prt1_p2.a < 450)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.a % 25) = 0))
+ -> Nested Loop Left Join
+ Output: prt2_p3.b, prt2_p3.c, a, c
+ Join Filter: (a = prt2_p3.b)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.a % 25) = 0))
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(26 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 300 | 0300 | 300 | 0300
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Sort Key: prt1_p1.a, b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, b, c
+ Hash Cond: (prt1_p1.a = b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a < 450) AND ((prt1_p1.a % 25) = 0))
+ -> Hash
+ Output: b, c
+ -> Result
+ Output: b, c
+ One-Time Filter: false
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a < 450) AND ((prt1_p2.a % 25) = 0))
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b > 250) AND ((prt2_p2.b % 25) = 0))
+ -> Hash Full Join
+ Output: a, c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt2_p3.b = a)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b > 250) AND ((prt2_p3.b % 25) = 0))
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | |
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | |
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ | | 375 | 0375
+ | | 450 | 0450
+ | | 525 | 0525
+(12 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(47 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.a = t2.a)
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1_2.a = t2_2.a)
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1_1.a = t2_1.a)
+(51 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: (t3.b = t2.a)
+ -> Seq Scan on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Hash
+ Output: t2.a
+ -> Seq Scan on public.prt1_p1 t2
+ Output: t2.a
+ Filter: (t1.b = t2.a)
+ -> Hash Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Hash Cond: (t3_1.b = t2_2.a)
+ -> Seq Scan on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Hash
+ Output: t2_2.a
+ -> Seq Scan on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Filter: (t1.b = t2_2.a)
+ -> Hash Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Hash Cond: (t3_2.b = t2_1.a)
+ -> Seq Scan on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+ -> Hash
+ Output: t2_1.a
+ -> Seq Scan on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Filter: (t1.b = t2_1.a)
+(49 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (((t2.b + t2.a) / 2) = ((t1.a + t1.b) / 2))
+ -> Seq Scan on public.prt2_e_p1 t2
+ Output: t2.b, t2.c, t2.a
+ -> Hash
+ Output: t1.a, t1.c, t1.b
+ -> Seq Scan on public.prt1_e_p1 t1
+ Output: t1.a, t1.c, t1.b
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: (((t2_1.b + t2_1.a) / 2) = ((t1_1.a + t1_1.b) / 2))
+ -> Seq Scan on public.prt2_e_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Hash
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Seq Scan on public.prt1_e_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: (((t2_2.b + t2_2.a) / 2) = ((t1_2.a + t1_2.b) / 2))
+ -> Seq Scan on public.prt2_e_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Hash
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Seq Scan on public.prt1_e_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ Filter: ((t1_2.a % 25) = 0)
+(34 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (((t3_2.a + t3_2.b) / 2) = t2_2.b)
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | |
+ 100 | 0100 | | | |
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | |
+ 250 | 0250 | | | |
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | |
+ 400 | 0400 | | | |
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | |
+ 550 | 0550 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: (t2.b = t1.a)
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: (t1.a = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = t1_2.a)
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = t1_1.a)
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: (t1.a = t2.b)
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: (t2.b = ((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Hash Cond: (t1_2.a = t2_1.b)
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: (t2_1.b = ((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Hash Cond: (t1_1.a = t2_2.b)
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, ((prt1_e_p1.a + prt1_e_p1.b)), prt1_e_p1.c
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, (prt1_e_p1.a + prt1_e_p1.b), prt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c, prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt1_p1.c, prt2_p1.b, prt2_p1.c
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, prt1_p1.c
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, prt2_p1.c
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, prt2_p1.c
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, prt1_e_p1.c
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c, prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt1_p2.c, prt2_p2.b, prt2_p2.c
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, prt1_p2.c
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, prt2_p2.c
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, prt2_p2.c
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, prt1_e_p2.c
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c, prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt1_p3.c, prt2_p3.b, prt2_p3.c
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, prt1_p3.c
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, prt2_p3.c
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, prt2_p3.c
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, prt1_e_p3.c
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+ | | 75 | 0075 | |
+ | | 225 | 0225 | |
+ | | 375 | 0375 | |
+ | | 525 | 0525 | |
+(16 rows)
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), ((prt1_e_p1.a + prt1_e_p1.b)), (50)
+ Sort Key: prt1_p1.a, prt2_p1.b, ((prt1_e_p1.a + prt1_e_p1.b))
+ -> Result
+ Output: prt1_p1.a, (50), prt2_p1.b, (75), (prt1_e_p1.a + prt1_e_p1.b), (50)
+ -> Append
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, prt1_e_p1.a, prt1_e_p1.b, (50), (75), (50)
+ Hash Cond: (prt1_p1.a = ((prt1_e_p1.a + prt1_e_p1.b) / 2))
+ Filter: ((prt1_p1.a = (50)) OR (prt2_p1.b = (75)) OR (((prt1_e_p1.a + prt1_e_p1.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p1.a, prt2_p1.b, (50), (75)
+ Hash Cond: (prt1_p1.a = prt2_p1.b)
+ -> Seq Scan on public.prt1_p1
+ Output: prt1_p1.a, 50
+ Filter: ((prt1_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_p1.b, (75)
+ -> Seq Scan on public.prt2_p1
+ Output: prt2_p1.b, 75
+ Filter: ((prt2_p1.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p1.a, prt1_e_p1.b, (50)
+ -> Seq Scan on public.prt1_e_p1
+ Output: prt1_e_p1.a, prt1_e_p1.b, 50
+ Filter: ((prt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, prt1_e_p2.a, prt1_e_p2.b, (50), (75), (50)
+ Hash Cond: (prt1_p2.a = ((prt1_e_p2.a + prt1_e_p2.b) / 2))
+ Filter: ((prt1_p2.a = (50)) OR (prt2_p2.b = (75)) OR (((prt1_e_p2.a + prt1_e_p2.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p2.a, prt2_p2.b, (50), (75)
+ Hash Cond: (prt1_p2.a = prt2_p2.b)
+ -> Seq Scan on public.prt1_p2
+ Output: prt1_p2.a, 50
+ Filter: ((prt1_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_p2.b, (75)
+ -> Seq Scan on public.prt2_p2
+ Output: prt2_p2.b, 75
+ Filter: ((prt2_p2.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p2.a, prt1_e_p2.b, (50)
+ -> Seq Scan on public.prt1_e_p2
+ Output: prt1_e_p2.a, prt1_e_p2.b, 50
+ Filter: ((prt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, prt1_e_p3.a, prt1_e_p3.b, (50), (75), (50)
+ Hash Cond: (prt1_p3.a = ((prt1_e_p3.a + prt1_e_p3.b) / 2))
+ Filter: ((prt1_p3.a = (50)) OR (prt2_p3.b = (75)) OR (((prt1_e_p3.a + prt1_e_p3.b) / 2) = (50)))
+ -> Hash Full Join
+ Output: prt1_p3.a, prt2_p3.b, (50), (75)
+ Hash Cond: (prt1_p3.a = prt2_p3.b)
+ -> Seq Scan on public.prt1_p3
+ Output: prt1_p3.a, 50
+ Filter: ((prt1_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_p3.b, (75)
+ -> Seq Scan on public.prt2_p3
+ Output: prt2_p3.b, 75
+ Filter: ((prt2_p3.b % 25) = 0)
+ -> Hash
+ Output: prt1_e_p3.a, prt1_e_p3.b, (50)
+ -> Seq Scan on public.prt1_e_p3
+ Output: prt1_e_p3.a, prt1_e_p3.b, 50
+ Filter: ((prt1_e_p3.a % 25) = 0)
+(66 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | phv | b | phv | ?column? | phv
+----+-----+----+-----+----------+-----
+ 50 | 50 | | | 100 | 50
+ | | 75 | 75 | |
+(2 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t2.a, t2.b
+ Sort Key: t1_3.b
+ -> Hash Join
+ Output: t1_3.b, t2.a, t2.b
+ Hash Cond: (((t2.a + t2.b) / 2) = t1_3.b)
+ -> Seq Scan on public.prt1_e_p1 t2
+ Output: t2.a, t2.b
+ -> Hash
+ Output: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ Filter: ((t1_3.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Sort Key: t1_4.b
+ -> Hash Join
+ Output: t1_4.b, t2_1.a, t2_1.b
+ Hash Cond: (((t2_1.a + t2_1.b) / 2) = t1_4.b)
+ -> Seq Scan on public.prt1_e_p2 t2_1
+ Output: t2_1.a, t2_1.b
+ -> Hash
+ Output: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ Filter: ((t1_4.b % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Sort Key: t1_5.b
+ -> Hash Join
+ Output: t1_5.b, t2_2.a, t2_2.b
+ Hash Cond: (((t2_2.a + t2_2.b) / 2) = t1_5.b)
+ -> Seq Scan on public.prt1_e_p3 t2_2
+ Output: t2_2.a, t2_2.b
+ -> Hash
+ Output: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ Filter: ((t1_5.b % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Sort
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Sort Key: t1_3.b
+ -> Hash Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Hash Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Hash
+ Output: t1_6.a, t1_6.b
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Sort
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Sort Key: t1_4.b
+ -> Hash Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Hash Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Hash
+ Output: t1_7.a, t1_7.b
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Sort
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Sort Key: t1_5.b
+ -> Hash Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Hash Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Hash
+ Output: t1_8.a, t1_8.b
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(68 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = (((t1_6.a + t1_6.b) / 2)))
+ -> Sort
+ Output: t1_3.b
+ Sort Key: t1_3.b
+ -> Seq Scan on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Sort
+ Output: t1_6.a, t1_6.b, (((t1_6.a + t1_6.b) / 2))
+ Sort Key: (((t1_6.a + t1_6.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b, ((t1_6.a + t1_6.b) / 2)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Sort
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = (((t1_7.a + t1_7.b) / 2)))
+ -> Sort
+ Output: t1_4.b
+ Sort Key: t1_4.b
+ -> Seq Scan on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Sort
+ Output: t1_7.a, t1_7.b, (((t1_7.a + t1_7.b) / 2))
+ Sort Key: (((t1_7.a + t1_7.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b, ((t1_7.a + t1_7.b) / 2)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Sort
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = (((t1_8.a + t1_8.b) / 2)))
+ -> Sort
+ Output: t1_5.b
+ Sort Key: t1_5.b
+ -> Seq Scan on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Sort
+ Output: t1_8.a, t1_8.b, (((t1_8.a + t1_8.b) / 2))
+ Sort Key: (((t1_8.a + t1_8.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b, ((t1_8.a + t1_8.b) / 2)
+ Filter: ((t1_8.a % 25) = 0)
+(77 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: ((((t3.a + t3.b) / 2)) = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, (((t3.a + t3.b) / 2))
+ Sort Key: (((t3.a + t3.b) / 2))
+ -> Seq Scan on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c, ((t3.a + t3.b) / 2)
+ Filter: ((t3.a % 25) = 0)
+ -> Sort
+ Output: t1.a, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Sort
+ Output: t2.b, t2.c
+ Sort Key: t2.b
+ -> Seq Scan on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: ((((t3_1.a + t3_1.b) / 2)) = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, (((t3_1.a + t3_1.b) / 2))
+ Sort Key: (((t3_1.a + t3_1.b) / 2))
+ -> Seq Scan on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c, ((t3_1.a + t3_1.b) / 2)
+ Filter: ((t3_1.a % 25) = 0)
+ -> Sort
+ Output: t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Seq Scan on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Sort
+ Output: t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Seq Scan on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: ((((t3_2.a + t3_2.b) / 2)) = t1_1.a)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, (((t3_2.a + t3_2.b) / 2))
+ Sort Key: (((t3_2.a + t3_2.b) / 2))
+ -> Seq Scan on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c, ((t3_2.a + t3_2.b) / 2)
+ Filter: ((t3_2.a % 25) = 0)
+ -> Sort
+ Output: t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Seq Scan on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Sort
+ Output: t2_2.b, t2_2.c
+ Sort Key: t2_2.b
+ -> Seq Scan on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(81 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SET enable_seqscan TO off;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Merge Cond: (t2.b = t1.a)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Sort Key: t2.b
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t2.b)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_2.a, t1_2.c
+ Merge Cond: (t2_1.b = t1_2.a)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Sort Key: t2_1.b
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t2_1.b)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Merge Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = ((t3_2.a + t3_2.b) / 2))
+ -> Merge Left Join
+ Output: t2_2.b, t2_2.c, t1_1.a, t1_1.c
+ Merge Cond: (t2_2.b = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(51 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ | | | | 100 | 0050
+ | | | | 200 | 0100
+ | | | | 400 | 0200
+ | | | | 500 | 0250
+ | | | | 700 | 0350
+ | | | | 800 | 0400
+ | | | | 1000 | 0500
+ | | | | 1100 | 0550
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Merge Append
+ Sort Key: t1.a
+ -> Merge Semi Join
+ Output: t1.a, t1.b, t1.c
+ Merge Cond: (t1.a = t1_3.b)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Materialize
+ Output: t1_3.b, t1_6.a, t1_6.b
+ -> Merge Semi Join
+ Output: t1_3.b, t1_6.a, t1_6.b
+ Merge Cond: (t1_3.b = ((t1_6.a + t1_6.b) / 2))
+ -> Index Only Scan using iprt2_p1_b on public.prt2_p1 t1_3
+ Output: t1_3.b
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t1_6
+ Output: t1_6.a, t1_6.b
+ Filter: ((t1_6.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Merge Cond: (t1_2.a = t1_4.b)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Materialize
+ Output: t1_4.b, t1_7.a, t1_7.b
+ -> Merge Semi Join
+ Output: t1_4.b, t1_7.a, t1_7.b
+ Merge Cond: (t1_4.b = ((t1_7.a + t1_7.b) / 2))
+ -> Index Only Scan using iprt2_p2_b on public.prt2_p2 t1_4
+ Output: t1_4.b
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t1_7
+ Output: t1_7.a, t1_7.b
+ Filter: ((t1_7.a % 25) = 0)
+ -> Merge Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Merge Cond: (t1_1.a = t1_5.b)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Materialize
+ Output: t1_5.b, t1_8.a, t1_8.b
+ -> Merge Semi Join
+ Output: t1_5.b, t1_8.a, t1_8.b
+ Merge Cond: (t1_5.b = ((t1_8.a + t1_8.b) / 2))
+ -> Index Only Scan using iprt2_p3_b on public.prt2_p3 t1_5
+ Output: t1_5.b
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t1_8
+ Output: t1_8.a, t1_8.b
+ Filter: ((t1_8.a % 25) = 0)
+(50 rows)
+
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0150
+ 300 | 300 | 0300
+ 450 | 450 | 0450
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Merge Cond: (t1.a = t2.b)
+ -> Sort
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Sort Key: t1.a
+ -> Merge Left Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Merge Cond: (((t3.a + t3.b) / 2) = t1.a)
+ -> Index Scan using iprt1_e_p1_ab2 on public.prt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.c
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t2
+ Output: t2.b, t2.c
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c, t2_1.b, t2_1.c
+ Merge Cond: (t1_2.a = t2_1.b)
+ -> Sort
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Sort Key: t1_2.a
+ -> Merge Left Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_2.a, t1_2.c
+ Merge Cond: (((t3_1.a + t3_1.b) / 2) = t1_2.a)
+ -> Index Scan using iprt1_e_p2_ab2 on public.prt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c, t2_2.b, t2_2.c
+ Merge Cond: (t1_1.a = t2_2.b)
+ -> Sort
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Sort Key: t1_1.a
+ -> Merge Left Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_1.a, t1_1.c
+ Merge Cond: (((t3_2.a + t3_2.b) / 2) = t1_1.a)
+ -> Index Scan using iprt1_e_p3_ab2 on public.prt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+(54 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+------
+ 0 | 0000 | 0 | 0000 | 0 | 0000
+ 50 | 0050 | | | 100 | 0050
+ 100 | 0100 | | | 200 | 0100
+ 150 | 0150 | 150 | 0150 | 300 | 0150
+ 200 | 0200 | | | 400 | 0200
+ 250 | 0250 | | | 500 | 0250
+ 300 | 0300 | 300 | 0300 | 600 | 0300
+ 350 | 0350 | | | 700 | 0350
+ 400 | 0400 | | | 800 | 0400
+ 450 | 0450 | 450 | 0450 | 900 | 0450
+ 500 | 0500 | | | 1000 | 0500
+ 550 | 0550 | | | 1100 | 0550
+(12 rows)
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Result
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.a)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t3_1.a, (LEAST(t1_2.a, t2_2.a, t3_1.a))
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1_2.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1_2.a)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t3_2.a, (LEAST(t1_1.a, t2_1.a, t3_2.a))
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1_1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1_1.a)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(43 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Merge Append
+ Sort Key: t1.a
+ -> Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Seq Scan on public.prt1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Index Scan using iprt1_p1_a on public.prt1_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Index Scan using iprt1_p3_a on public.prt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Index Scan using iprt1_p2_a on public.prt1_p2 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Append
+ -> Merge Join
+ Output: t2.a, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Merge Cond: (t2.a = t3.b)
+ -> Index Only Scan using iprt1_p1_a on public.prt1_p1 t2
+ Output: t2.a
+ Index Cond: (t2.a = t1.b)
+ -> Index Scan using iprt2_p1_b on public.prt2_p1 t3
+ Output: t3.a, t3.b
+ -> Merge Join
+ Output: t2_2.a, t3_1.a, LEAST(t1.a, t2_2.a, t3_1.a)
+ Merge Cond: (t2_2.a = t3_1.b)
+ -> Index Only Scan using iprt1_p2_a on public.prt1_p2 t2_2
+ Output: t2_2.a
+ Index Cond: (t2_2.a = t1.b)
+ -> Index Scan using iprt2_p2_b on public.prt2_p2 t3_1
+ Output: t3_1.a, t3_1.b
+ -> Merge Join
+ Output: t2_1.a, t3_2.a, LEAST(t1.a, t2_1.a, t3_2.a)
+ Merge Cond: (t2_1.a = t3_2.b)
+ -> Index Only Scan using iprt1_p3_a on public.prt1_p3 t2_1
+ Output: t2_1.a
+ Index Cond: (t2_1.a = t1.b)
+ -> Index Scan using iprt2_p3_b on public.prt2_p3 t3_2
+ Output: t3_2.a, t3_2.b
+(44 rows)
+
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t3a | least
+-----+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | |
+ 100 | 100 | 0100 | | |
+ 150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | |
+ 250 | 250 | 0250 | | |
+ 300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | |
+ 400 | 400 | 0400 | | |
+ 450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | |
+ 550 | 550 | 0550 | | |
+(12 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((((t1.a + t1.b) / 2) = t2.b) AND (t1.a = ((t2.b + t2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p1 t1
+ Output: t1.a, t1.c, t1.b
+ -> Hash
+ Output: t2.b, t2.c, t2.a
+ -> Seq Scan on public.prt2_m_p1 t2
+ Output: t2.b, t2.c, t2.a
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((((t1_1.a + t1_1.b) / 2) = t2_1.b) AND (t1_1.a = ((t2_1.b + t2_1.a) / 2)))
+ -> Seq Scan on public.prt1_m_p2 t1_1
+ Output: t1_1.a, t1_1.c, t1_1.b
+ -> Hash
+ Output: t2_1.b, t2_1.c, t2_1.a
+ -> Seq Scan on public.prt2_m_p2 t2_1
+ Output: t2_1.b, t2_1.c, t2_1.a
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((((t1_2.a + t1_2.b) / 2) = t2_2.b) AND (t1_2.a = ((t2_2.b + t2_2.a) / 2)))
+ -> Seq Scan on public.prt1_m_p3 t1_2
+ Output: t1_2.a, t1_2.c, t1_2.b
+ -> Hash
+ Output: t2_2.b, t2_2.c, t2_2.a
+ -> Seq Scan on public.prt2_m_p3 t2_2
+ Output: t2_2.b, t2_2.c, t2_2.a
+ Filter: ((t2_2.b % 25) = 0)
+(36 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Sort Key: prt1_m_p1.a, prt2_m_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt2_m_p1.b, prt2_m_p1.c
+ Hash Cond: ((prt1_m_p1.a = ((prt2_m_p1.b + prt2_m_p1.a) / 2)) AND (((prt1_m_p1.a + prt1_m_p1.b) / 2) = prt2_m_p1.b))
+ -> Seq Scan on public.prt1_m_p1
+ Output: prt1_m_p1.a, prt1_m_p1.c, prt1_m_p1.b
+ Filter: ((prt1_m_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ -> Seq Scan on public.prt2_m_p1
+ Output: prt2_m_p1.b, prt2_m_p1.c, prt2_m_p1.a
+ Filter: ((prt2_m_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt2_m_p2.b, prt2_m_p2.c
+ Hash Cond: ((prt1_m_p2.a = ((prt2_m_p2.b + prt2_m_p2.a) / 2)) AND (((prt1_m_p2.a + prt1_m_p2.b) / 2) = prt2_m_p2.b))
+ -> Seq Scan on public.prt1_m_p2
+ Output: prt1_m_p2.a, prt1_m_p2.c, prt1_m_p2.b
+ Filter: ((prt1_m_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ -> Seq Scan on public.prt2_m_p2
+ Output: prt2_m_p2.b, prt2_m_p2.c, prt2_m_p2.a
+ Filter: ((prt2_m_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt2_m_p3.b, prt2_m_p3.c
+ Hash Cond: ((prt1_m_p3.a = ((prt2_m_p3.b + prt2_m_p3.a) / 2)) AND (((prt1_m_p3.a + prt1_m_p3.b) / 2) = prt2_m_p3.b))
+ -> Seq Scan on public.prt1_m_p3
+ Output: prt1_m_p3.a, prt1_m_p3.c, prt1_m_p3.b
+ Filter: ((prt1_m_p3.a % 25) = 0)
+ -> Hash
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ -> Seq Scan on public.prt2_m_p3
+ Output: prt2_m_p3.b, prt2_m_p3.c, prt2_m_p3.a
+ Filter: ((prt2_m_p3.b % 25) = 0)
+(37 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.a)), (avg(t2.b)), (avg((t3.a + t3.b))), t1.c, t2.c, t3.c
+ Sort Key: t1.c, t3.c
+ -> HashAggregate
+ Output: avg(t1.a), avg(t2.b), avg((t3.a + t3.b)), t1.c, t2.c, t3.c
+ Group Key: t1.c, t2.c, t3.c
+ -> Result
+ Output: t1.c, t2.c, t3.c, t1.a, t2.b, t3.a, t3.b
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t1.c = t2.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t1_1.c = t2_1.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t1_2.c = t2_2.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ -> Hash Join
+ Output: t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+(57 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+ avg | avg | avg | c | c | c
+----------------------+----------------------+-----------------------+------+------+-------
+ 24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
+ 74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
+ 124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
+ 174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
+ 224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
+ 274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
+ 324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
+ 374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
+ 424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
+ 474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
+ 524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
+ 574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t1.a) AND (ltrim(t3.c, 'A'::text) = t1.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t1_1.a) AND (ltrim(t3_1.c, 'A'::text) = t1_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t1_2.a) AND (ltrim(t3_2.c, 'A'::text) = t1_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c, t3.a, t3.b, t3.c
+ Hash Cond: ((t3.a = t2.b) AND (ltrim(t3.c, 'A'::text) = t2.c))
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c, t3_1.a, t3_1.b, t3_1.c
+ Hash Cond: ((t3_1.a = t2_1.b) AND (ltrim(t3_1.c, 'A'::text) = t2_1.c))
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c, t3_2.a, t3_2.b, t3_2.c
+ Hash Cond: ((t3_2.a = t2_2.b) AND (ltrim(t3_2.c, 'A'::text) = t2_2.c))
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | |
+ 100 | 0002 | | | |
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | |
+ 250 | 0005 | | | |
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | |
+ 400 | 0008 | | | |
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | |
+ 550 | 0011 | | | |
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND (t2.c = t1.c))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t1.a, t1.c
+ Hash Cond: ((t1.c = ltrim(t3.c, 'A'::text)) AND (t1.a = t3.a))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND (t2_1.c = t1_1.c))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.c = ltrim(t3_1.c, 'A'::text)) AND (t1_1.a = t3_1.a))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND (t2_2.c = t1_2.c))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.c = ltrim(t3_2.c, 'A'::text)) AND (t1_2.a = t3_2.a))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c, ((t3.a + t3.b)), t3.c
+ Sort Key: t1.a, t2.b, ((t3.a + t3.b))
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c, (t3.a + t3.b), t3.c
+ -> Append
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND (t1.c = t2.c))
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ -> Hash Right Join
+ Output: t3.a, t3.b, t3.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t3.a) AND (t2.c = ltrim(t3.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t3.a, t3.b, t3.c
+ -> Seq Scan on public.plt1_e_p1 t3
+ Output: t3.a, t3.b, t3.c
+ Filter: ((t3.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND (t1_1.c = t2_1.c))
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ -> Hash Right Join
+ Output: t3_1.a, t3_1.b, t3_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t3_1.a) AND (t2_1.c = ltrim(t3_1.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p2 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Seq Scan on public.plt1_e_p2 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ Filter: ((t3_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND (t1_2.c = t2_2.c))
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ -> Hash Right Join
+ Output: t3_2.a, t3_2.b, t3_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t3_2.a) AND (t2_2.c = ltrim(t3_2.c, 'A'::text)))
+ -> Seq Scan on public.plt2_p3 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Seq Scan on public.plt1_e_p3 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ Filter: ((t3_2.a % 25) = 0)
+(57 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ | | | | 100 | A0001
+ | | | | 200 | A0002
+ | | | | 400 | A0004
+ | | | | 500 | A0005
+ | | | | 700 | A0007
+ | | | | 800 | A0008
+ | | | | 1000 | A0010
+ | | | | 1100 | A0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, ((plt1_e_p1.a + plt1_e_p1.b)), plt1_e_p1.c
+ Sort Key: plt1_p1.a, plt2_p1.b, ((plt1_e_p1.a + plt1_e_p1.b))
+ -> Result
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, (plt1_e_p1.a + plt1_e_p1.b), plt1_e_p1.c
+ -> Append
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c, plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Hash Cond: ((plt1_p1.a = plt1_e_p1.a) AND (plt1_p1.c = ltrim(plt1_e_p1.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p1.a, plt1_p1.c, plt2_p1.b, plt2_p1.c
+ Hash Cond: ((plt1_p1.a = plt2_p1.b) AND (plt1_p1.c = plt2_p1.c))
+ -> Seq Scan on public.plt1_p1
+ Output: plt1_p1.a, plt1_p1.c
+ Filter: ((plt1_p1.a % 25) = 0)
+ -> Hash
+ Output: plt2_p1.b, plt2_p1.c
+ -> Seq Scan on public.plt2_p1
+ Output: plt2_p1.b, plt2_p1.c
+ Filter: ((plt2_p1.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ -> Seq Scan on public.plt1_e_p1
+ Output: plt1_e_p1.a, plt1_e_p1.b, plt1_e_p1.c
+ Filter: ((plt1_e_p1.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c, plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Hash Cond: ((plt1_p2.a = plt1_e_p2.a) AND (plt1_p2.c = ltrim(plt1_e_p2.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p2.a, plt1_p2.c, plt2_p2.b, plt2_p2.c
+ Hash Cond: ((plt1_p2.a = plt2_p2.b) AND (plt1_p2.c = plt2_p2.c))
+ -> Seq Scan on public.plt1_p2
+ Output: plt1_p2.a, plt1_p2.c
+ Filter: ((plt1_p2.a % 25) = 0)
+ -> Hash
+ Output: plt2_p2.b, plt2_p2.c
+ -> Seq Scan on public.plt2_p2
+ Output: plt2_p2.b, plt2_p2.c
+ Filter: ((plt2_p2.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ -> Seq Scan on public.plt1_e_p2
+ Output: plt1_e_p2.a, plt1_e_p2.b, plt1_e_p2.c
+ Filter: ((plt1_e_p2.a % 25) = 0)
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c, plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Hash Cond: ((plt1_p3.a = plt1_e_p3.a) AND (plt1_p3.c = ltrim(plt1_e_p3.c, 'A'::text)))
+ -> Hash Full Join
+ Output: plt1_p3.a, plt1_p3.c, plt2_p3.b, plt2_p3.c
+ Hash Cond: ((plt1_p3.a = plt2_p3.b) AND (plt1_p3.c = plt2_p3.c))
+ -> Seq Scan on public.plt1_p3
+ Output: plt1_p3.a, plt1_p3.c
+ Filter: ((plt1_p3.a % 25) = 0)
+ -> Hash
+ Output: plt2_p3.b, plt2_p3.c
+ -> Seq Scan on public.plt2_p3
+ Output: plt2_p3.b, plt2_p3.c
+ Filter: ((plt2_p3.b % 25) = 0)
+ -> Hash
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ -> Seq Scan on public.plt1_e_p3
+ Output: plt1_e_p3.a, plt1_e_p3.b, plt1_e_p3.c
+ Filter: ((plt1_e_p3.a % 25) = 0)
+(63 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+ a | c | b | c | ?column? | c
+-----+------+-----+------+----------+-------
+ 0 | 0000 | 0 | 0000 | 0 | A0000
+ 50 | 0001 | | | 100 | A0001
+ 100 | 0002 | | | 200 | A0002
+ 150 | 0003 | 150 | 0003 | 300 | A0003
+ 200 | 0004 | | | 400 | A0004
+ 250 | 0005 | | | 500 | A0005
+ 300 | 0006 | 300 | 0006 | 600 | A0006
+ 350 | 0007 | | | 700 | A0007
+ 400 | 0008 | | | 800 | A0008
+ 450 | 0009 | 450 | 0009 | 900 | A0009
+ 500 | 0010 | | | 1000 | A0010
+ 550 | 0011 | | | 1100 | A0011
+ | | 75 | 0001 | |
+ | | 225 | 0004 | |
+ | | 375 | 0007 | |
+ | | 525 | 0010 | |
+(16 rows)
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t2.c
+ Hash Cond: (t1_3.c = ltrim(t2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t2.c
+ -> Seq Scan on public.plt1_e_p1 t2
+ Output: t2.c
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t2_1.c
+ Hash Cond: (t1_4.c = ltrim(t2_1.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t2_1.c
+ -> Seq Scan on public.plt1_e_p2 t2_1
+ Output: t2_1.c
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t2_2.c
+ Hash Cond: (t1_5.c = ltrim(t2_2.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t2_2.c
+ -> Seq Scan on public.plt1_e_p3 t2_2
+ Output: t2_2.c
+(49 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c
+ Sort Key: t1.a
+ -> Append
+ -> Nested Loop Semi Join
+ Output: t1.a, t1.b, t1.c
+ Join Filter: (t1.c = t1_3.c)
+ -> Seq Scan on public.plt1_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.c, t1_6.c
+ Hash Cond: (t1_3.c = ltrim(t1_6.c, 'A'::text))
+ -> Seq Scan on public.plt2_p1 t1_3
+ Output: t1_3.c
+ -> Hash
+ Output: t1_6.c
+ -> HashAggregate
+ Output: t1_6.c
+ Group Key: ltrim(t1_6.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p1 t1_6
+ Output: t1_6.c, ltrim(t1_6.c, 'A'::text)
+ Filter: ((t1_6.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Join Filter: (t1_1.c = t1_4.c)
+ -> Seq Scan on public.plt1_p2 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_4.c, t1_7.c
+ Hash Cond: (t1_4.c = ltrim(t1_7.c, 'A'::text))
+ -> Seq Scan on public.plt2_p2 t1_4
+ Output: t1_4.c
+ -> Hash
+ Output: t1_7.c
+ -> HashAggregate
+ Output: t1_7.c
+ Group Key: ltrim(t1_7.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p2 t1_7
+ Output: t1_7.c, ltrim(t1_7.c, 'A'::text)
+ Filter: ((t1_7.a % 25) = 0)
+ -> Nested Loop Semi Join
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Join Filter: (t1_2.c = t1_5.c)
+ -> Seq Scan on public.plt1_p3 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_5.c, t1_8.c
+ Hash Cond: (t1_5.c = ltrim(t1_8.c, 'A'::text))
+ -> Seq Scan on public.plt2_p3 t1_5
+ Output: t1_5.c
+ -> Hash
+ Output: t1_8.c
+ -> HashAggregate
+ Output: t1_8.c
+ Group Key: ltrim(t1_8.c, 'A'::text)
+ -> Seq Scan on public.plt1_e_p3 t1_8
+ Output: t1_8.c, ltrim(t1_8.c, 'A'::text)
+ Filter: ((t1_8.a % 25) = 0)
+(61 rows)
+
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 50 | 50 | 0001
+ 100 | 100 | 0002
+ 150 | 150 | 0003
+ 200 | 200 | 0004
+ 250 | 250 | 0005
+ 300 | 300 | 0006
+ 350 | 350 | 0007
+ 400 | 400 | 0008
+ 450 | 450 | 0009
+ 500 | 500 | 0010
+ 550 | 550 | 0011
+(12 rows)
+
+--
+-- negative testcases
+--
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+ QUERY PLAN
+----------------------------------
+ Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+ QUERY PLAN
+--------------------------------------
+ Result
+ Output: prt1.a, prt1.c, t2.b, t2.c
+ One-Time Filter: false
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+---------------------------------------------------
+ Sort
+ Output: a, c, t2.b, t2.c
+ Sort Key: a, t2.b
+ -> Hash Left Join
+ Output: a, c, t2.b, t2.c
+ Hash Cond: (t2.b = a)
+ -> Append
+ -> Seq Scan on public.prt2 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.a % 25) = 0)
+ -> Seq Scan on public.prt2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.a % 25) = 0)
+ -> Seq Scan on public.prt2_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.a % 25) = 0)
+ -> Hash
+ Output: a, c
+ -> Result
+ Output: a, c
+ One-Time Filter: false
+(24 rows)
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: (t1.a = t2.a)
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt4_n t2
+ -> Seq Scan on prt4_n_p1 t2_1
+ -> Seq Scan on prt4_n_p2 t2_2
+ -> Seq Scan on prt4_n_p3 t2_3
+(13 rows)
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+ QUERY PLAN
+---------------------------------------------------------
+ Nested Loop Left Join
+ -> Append
+ -> Seq Scan on prt1 t1
+ -> Seq Scan on prt1_p1 t1_1
+ -> Seq Scan on prt1_p3 t1_2
+ -> Seq Scan on prt1_p2 t1_3
+ -> Append
+ -> Seq Scan on prt2 t2
+ Filter: (t1.a < b)
+ -> Index Scan using iprt2_p1_b on prt2_p1 t2_1
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p2_b on prt2_p2 t2_2
+ Index Cond: (t1.a < b)
+ -> Index Scan using iprt2_p3_b on prt2_p3 t2_3
+ Index Cond: (t1.a < b)
+(15 rows)
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (((t2.b + t2.a) / 2) = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_m t2
+ -> Seq Scan on prt2_m_p1 t2_1
+ -> Seq Scan on prt2_m_p2 t2_2
+ -> Seq Scan on prt2_m_p3 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_m t1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p1 t1_1
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p2 t1_2
+ Filter: ((a % 25) = 0)
+ -> Seq Scan on prt1_m_p3 t1_3
+ Filter: ((a % 25) = 0)
+(17 rows)
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+ QUERY PLAN
+----------------------------------------------
+ Hash Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Right Join
+ Hash Cond: (t2.c = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt2_n t2
+ -> Seq Scan on prt2_n_p1 t2_1
+ -> Seq Scan on prt2_n_p2 t2_2
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(11 rows)
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Left Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
+ QUERY PLAN
+----------------------------------------------
+ Hash Full Join
+ Hash Cond: ((t2.c)::text = (t1.c)::text)
+ -> Append
+ -> Seq Scan on prt1 t2
+ -> Seq Scan on prt1_p1 t2_1
+ -> Seq Scan on prt1_p3 t2_2
+ -> Seq Scan on prt1_p2 t2_3
+ -> Hash
+ -> Append
+ -> Seq Scan on prt1_n t1
+ -> Seq Scan on prt1_n_p1 t1_1
+ -> Seq Scan on prt1_n_p2 t1_2
+(12 rows)
+
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index edeb2d6..ac38f50 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -103,7 +103,7 @@ test: publication subscription
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 27a46d7..1bf98a4 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -172,3 +172,4 @@ test: with
test: xml
test: event_trigger
test: stats
+test: partition_join
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
new file mode 100644
index 0000000..0322f1e
--- /dev/null
+++ b/src/test/regress/sql/partition_join.sql
@@ -0,0 +1,515 @@
+--
+-- PARTITION_JOIN
+-- Test partition-wise join between partitioned tables
+--
+
+--
+-- partitioned by a single column
+--
+CREATE TABLE prt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_p1 PARTITION OF prt1 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_p3 PARTITION OF prt1 FOR VALUES FROM (500) TO (600);
+CREATE TABLE prt1_p2 PARTITION OF prt1 FOR VALUES FROM (250) TO (500);
+INSERT INTO prt1 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1 AS SELECT * FROM prt1;
+
+CREATE TABLE prt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_p1 PARTITION OF prt2 FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_p2 PARTITION OF prt2 FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_p3 PARTITION OF prt2 FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2 SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+CREATE TABLE uprt2 AS SELECT * FROM prt2;
+
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) WHERE t1.phv = t1.b OR t2.phv = t2.b ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t1.phv, t2.b, t2.c, t2.phv FROM (SELECT 25 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 50 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+
+-- Join with pruned partitions from joining relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1 t1, uprt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450) t1 RIGHT JOIN (SELECT * FROM uprt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1 WHERE a < 450 AND a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE b > 250 AND b % 25 = 0) t2 ON t1.a = t2.b ORDER BY t1.a, t2.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b % 25 = 0) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- partitioned by expression
+--
+CREATE TABLE prt1_e (a int, b int, c varchar) PARTITION BY RANGE(((a + b)/2));
+CREATE TABLE prt1_e_p1 PARTITION OF prt1_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_e_p2 PARTITION OF prt1_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt1_e_p3 PARTITION OF prt1_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt1_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_e AS SELECT * FROM prt1_e;
+
+CREATE TABLE prt2_e (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2));
+CREATE TABLE prt2_e_p1 PARTITION OF prt2_e FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_e_p2 PARTITION OF prt2_e FOR VALUES FROM (250) TO (500);
+CREATE TABLE prt2_e_p3 PARTITION OF prt2_e FOR VALUES FROM (500) TO (600);
+INSERT INTO prt2_e SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_e;
+ANALYZE prt2_e_p1;
+ANALYZE prt2_e_p2;
+ANALYZE prt2_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_e AS SELECT * FROM prt2_e;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1, prt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1, uprt2_e t2 WHERE (t1.a + t1.b)/2 = (t2.b + t2.a)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_e t1 LEFT JOIN prt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_e t1 LEFT JOIN uprt2_e t2 ON (t1.a + t1.b)/2 = (t2.b + t2.a)/2 WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM prt1 t1, prt2 t2, prt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM uprt1 t1, uprt2 t2, uprt1_e t3 WHERE t1.a = t2.b AND t1.a = (t3.a + t3.b)/2 AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) LEFT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) LEFT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Cases with non-nullable expressions in subquery results;
+-- make sure these go to null as expected
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM prt1 WHERE prt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM prt2 WHERE prt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM prt1_e WHERE prt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.phv, t2.b, t2.phv, t3.a + t3.b, t3.phv FROM ((SELECT 50 phv, * FROM uprt1 WHERE uprt1.a % 25 = 0) t1 FULL JOIN (SELECT 75 phv, * FROM uprt2 WHERE uprt2.b % 25 = 0) t2 ON (t1.a = t2.b)) FULL JOIN (SELECT 50 phv, * FROM uprt1_e WHERE uprt1_e.a % 25 = 0) t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t1.a = t1.phv OR t2.b = t2.phv OR (t3.a + t3.b)/2 = t3.phv ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1, prt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1, uprt1_e t2 WHERE t1.b % 25 = 0 AND t1.b = (t2.a + t2.b)/2) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+-- test merge joins with and without using indexes
+SET enable_hashjoin TO off;
+SET enable_nestloop TO off;
+
+CREATE INDEX iprt1_p1_a on prt1_p1(a);
+CREATE INDEX iprt1_p2_a on prt1_p2(a);
+CREATE INDEX iprt1_p3_a on prt1_p3(a);
+CREATE INDEX iprt2_p1_b on prt2_p1(b);
+CREATE INDEX iprt2_p2_b on prt2_p2(b);
+CREATE INDEX iprt2_p3_b on prt2_p3(b);
+CREATE INDEX iprt1_e_p1_ab2 on prt1_e_p1(((a+b)/2));
+CREATE INDEX iprt1_e_p2_ab2 on prt1_e_p2(((a+b)/2));
+CREATE INDEX iprt1_e_p3_ab2 on prt1_e_p3(((a+b)/2));
+
+ANALYZE prt1;
+ANALYZE prt1_p1;
+ANALYZE prt1_p2;
+ANALYZE prt1_p3;
+ANALYZE prt2;
+ANALYZE prt2_p1;
+ANALYZE prt2_p2;
+ANALYZE prt2_p3;
+ANALYZE prt1_e;
+ANALYZE prt1_e_p1;
+ANALYZE prt1_e_p2;
+ANALYZE prt1_e_p3;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+SET enable_seqscan TO off;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 RIGHT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t2.b = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM prt1 t1 WHERE t1.a IN (SELECT t1.b FROM prt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM prt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uprt1 t1 WHERE t1.a IN (SELECT t1.b FROM uprt2 t1 WHERE t1.b IN (SELECT (t1.a + t1.b)/2 FROM uprt1_e t1 WHERE t1.a %25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uprt1 t1 LEFT JOIN uprt2 t2 ON t1.a = t2.b) RIGHT JOIN uprt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- lateral references and parameterized paths
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.a = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1 t2 JOIN prt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1 t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1 t2 JOIN uprt2 t3 ON (t2.a = t3.b)) ss
+ ON t1.b = ss.t2a WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+RESET enable_seqscan;
+
+--
+-- partitioned by multiple columns
+--
+CREATE TABLE prt1_m (a int, b int, c varchar) PARTITION BY RANGE(a, ((a + b)/2));
+CREATE TABLE prt1_m_p1 PARTITION OF prt1_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt1_m_p2 PARTITION OF prt1_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt1_m_p3 PARTITION OF prt1_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt1_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_m;
+ANALYZE prt1_m_p1;
+ANALYZE prt1_m_p2;
+ANALYZE prt1_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_m AS SELECT * FROM prt1_m;
+
+CREATE TABLE prt2_m (a int, b int, c varchar) PARTITION BY RANGE(((b + a)/2), b);
+CREATE TABLE prt2_m_p1 PARTITION OF prt2_m FOR VALUES FROM (0, 0) TO (250, 250);
+CREATE TABLE prt2_m_p2 PARTITION OF prt2_m FOR VALUES FROM (250, 250) TO (500, 500);
+CREATE TABLE prt2_m_p3 PARTITION OF prt2_m FOR VALUES FROM (500, 500) TO (600, 600);
+INSERT INTO prt2_m SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_m;
+ANALYZE prt2_m_p1;
+ANALYZE prt2_m_p2;
+ANALYZE prt2_m_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_m AS SELECT * FROM prt2_m;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 RIGHT JOIN prt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_m t1 RIGHT JOIN uprt2_m t2 ON t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2 WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_m WHERE prt1_m.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_m WHERE prt2_m.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_m t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_m t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = (t2.b + t2.a)/2 AND t2.b = (t1.a + t1.b)/2) ORDER BY t1.a, t2.b;
+
+--
+-- tests for list partitioned tables.
+--
+CREATE TABLE plt1 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt1_p1 PARTITION OF plt1 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_p2 PARTITION OF plt1 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_p3 PARTITION OF plt1 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1;
+ANALYZE plt1_p1;
+ANALYZE plt1_p2;
+ANALYZE plt1_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1 AS SELECT * FROM plt1;
+
+CREATE TABLE plt2 (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE plt2_p1 PARTITION OF plt2 FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt2_p2 PARTITION OF plt2 FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt2_p3 PARTITION OF plt2 FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE plt2;
+ANALYZE plt2_p1;
+ANALYZE plt2_p2;
+ANALYZE plt2_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt2 AS SELECT * FROM plt2;
+
+--
+-- list partitioned by expression
+--
+CREATE TABLE plt1_e (a int, b int, c text) PARTITION BY LIST(ltrim(c, 'A'));
+CREATE TABLE plt1_e_p1 PARTITION OF plt1_e FOR VALUES IN ('0000', '0003', '0004', '0010');
+CREATE TABLE plt1_e_p2 PARTITION OF plt1_e FOR VALUES IN ('0001', '0005', '0002', '0009');
+CREATE TABLE plt1_e_p3 PARTITION OF plt1_e FOR VALUES IN ('0006', '0007', '0008', '0011');
+INSERT INTO plt1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE plt1_e;
+ANALYZE plt1_e_p1;
+ANALYZE plt1_e_p2;
+ANALYZE plt1_e_p3;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uplt1_e AS SELECT * FROM plt1_e;
+
+--
+-- N-way join
+--
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM plt1 t1, plt2 t2, plt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM uplt1 t1, uplt2 t2, uplt1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) LEFT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 LEFT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 LEFT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (plt1 t1 RIGHT JOIN plt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN plt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (uplt1 t1 RIGHT JOIN uplt2 t2 ON t1.a = t2.b AND t1.c = t2.c) RIGHT JOIN uplt1_e t3 ON (t2.b = t3.a AND t2.c = ltrim(t3.c, 'A')) WHERE t3.a % 25 = 0 ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM plt1 WHERE plt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM plt2 WHERE plt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM plt1_e WHERE plt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM ((SELECT * FROM uplt1 WHERE uplt1.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uplt2 WHERE uplt2.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c)) FULL JOIN (SELECT * FROM uplt1_e WHERE uplt1_e.a % 25 = 0) t3 ON (t1.a = t3.a AND ltrim(t3.c, 'A') = t1.c) ORDER BY t1.a, t2.b, t3.a + t3.b;
+
+-- Semi-join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1, plt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1, uplt1_e t2 WHERE t1.c = ltrim(t2.c, 'A')) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM plt1 t1 WHERE t1.c IN (SELECT t1.c FROM plt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM plt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+SELECT t1.* FROM uplt1 t1 WHERE t1.c IN (SELECT t1.c FROM uplt2 t1 WHERE t1.c IN (SELECT ltrim(t1.c, 'A') FROM uplt1_e t1 WHERE t1.a % 25 = 0)) AND t1.a % 25 = 0 ORDER BY t1.a;
+
+--
+-- negative testcases
+--
+
+-- joins where one of the relations is proven empty
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a = 1 AND t1.a = 2;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 LEFT JOIN prt2 t2 ON t1.a = t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 RIGHT JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+CREATE TABLE prt1_n (a int, b int, c varchar) PARTITION BY RANGE(c);
+CREATE TABLE prt1_n_p1 PARTITION OF prt1_n FOR VALUES FROM ('0000') TO ('0250');
+CREATE TABLE prt1_n_p2 PARTITION OF prt1_n FOR VALUES FROM ('0250') TO ('0500');
+INSERT INTO prt1_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 499, 2) i;
+ANALYZE prt1_n;
+ANALYZE prt1_n_p1;
+ANALYZE prt1_n_p2;
+
+CREATE TABLE prt2_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt2_n_p1 PARTITION OF prt2_n FOR VALUES IN ('0000', '0003', '0004', '0010', '0006', '0007');
+CREATE TABLE prt2_n_p2 PARTITION OF prt2_n FOR VALUES IN ('0001', '0005', '0002', '0009', '0008', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt2_n;
+ANALYZE prt2_n_p1;
+ANALYZE prt2_n_p2;
+
+CREATE TABLE prt3_n (a int, b int, c text) PARTITION BY LIST(c);
+CREATE TABLE prt3_n_p1 PARTITION OF prt3_n FOR VALUES IN ('0000', '0004', '0006', '0007');
+CREATE TABLE prt3_n_p2 PARTITION OF prt3_n FOR VALUES IN ('0001', '0002', '0008', '0010');
+CREATE TABLE prt3_n_p3 PARTITION OF prt3_n FOR VALUES IN ('0003', '0005', '0009', '0011');
+INSERT INTO prt2_n SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt3_n;
+ANALYZE prt3_n_p1;
+ANALYZE prt3_n_p2;
+ANALYZE prt3_n_p3;
+
+CREATE TABLE prt4_n (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE prt4_n_p1 PARTITION OF prt4_n FOR VALUES FROM (0) TO (300);
+CREATE TABLE prt4_n_p2 PARTITION OF prt4_n FOR VALUES FROM (300) TO (500);
+CREATE TABLE prt4_n_p3 PARTITION OF prt4_n FOR VALUES FROM (500) TO (600);
+INSERT INTO prt4_n SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt4_n;
+ANALYZE prt4_n_p1;
+ANALYZE prt4_n_p2;
+ANALYZE prt4_n_p3;
+
+-- partition-wise join can not be applied if the partition ranges differ
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt4_n t2 WHERE t1.a = t2.a;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 FULL JOIN prt4_n t2 ON t1.a = t2.a;
+
+-- partition-wise join can not be applied if there are no equi-join conditions
+-- between partition keys
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1 LEFT JOIN prt2 t2 ON (t1.a < t2.b);
+
+-- equi-join with join condition on partial keys does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1, prt2_m t2 WHERE t1.a = (t2.b + t2.a)/2 AND t1.a % 25 = 0;
+
+-- equi-join between out-of-order partition key columns does not qualify for
+-- partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.a = t2.b WHERE t1.a % 25 = 0;
+
+-- equi-join between non-key columns does not qualify for partition-wise join
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_m t1 LEFT JOIN prt2_m t2 ON t1.c = t2.c WHERE t1.a % 25 = 0;
+
+-- partition-wise join can not be applied for a join between list and range
+-- partitioned table
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1, prt2_n t2 WHERE t1.c = t2.c;
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 LEFT JOIN prt2_n t2 ON (t1.c = t2.c);
+
+-- partition-wise join can not be applied between tables with different
+-- partition lists
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 RIGHT JOIN prt1 t2 ON (t1.c = t2.c);
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_n t1 FULL JOIN prt1 t2 ON (t1.c = t2.c);
--
1.7.9.5
0008-Partition-wise-join-implementation.patchapplication/octet-stream; name=0008-Partition-wise-join-implementation.patchDownload
From 65764b810ac0f972dbd9513ff84397c29fea58c5 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 16:04:03 +0530
Subject: [PATCH 08/14] Partition-wise join implementation.
Implement partition-wise join for join between single level partitioned tables.
The details of this technique can be found in optimizer/README, where most of
the implementation has been explained.
We obtain clauses applicable to a child-join by translating corresponding
clauses of the parent. Because child-join can be computed by different
combinations of joining child relations, a given clause is required to be
translated multiple times. In order to reduce the memory consumption, we keep a
repository of child-clauses derived from a parent clause and search in that
repository before translating.
Tests for semi-join, those forcing a merge join for child-join and those
testing lateral join will crash with this patch. The tests testing joins with
partition pruning will also fail. Those crashes and failures are because the
existing code does not expect a child-join to appear in certain cases.
Following patches will fix that code.
---
src/backend/nodes/copyfuncs.c | 9 +
src/backend/optimizer/README | 53 ++++
src/backend/optimizer/path/allpaths.c | 321 +++++++++++++++++---
src/backend/optimizer/path/costsize.c | 3 +
src/backend/optimizer/path/joinpath.c | 21 +-
src/backend/optimizer/path/joinrels.c | 421 ++++++++++++++++++++++++++
src/backend/optimizer/plan/createplan.c | 228 +++++++++++++-
src/backend/optimizer/prep/prepunion.c | 160 ++++++++++
src/backend/optimizer/util/pathnode.c | 113 +++++++
src/backend/optimizer/util/placeholder.c | 55 ++++
src/backend/optimizer/util/relnode.c | 266 +++++++++++++++-
src/backend/utils/misc/guc.c | 28 ++
src/include/nodes/nodes.h | 1 +
src/include/nodes/relation.h | 57 ++++
src/include/optimizer/cost.h | 5 +
src/include/optimizer/pathnode.h | 6 +
src/include/optimizer/paths.h | 7 +
src/include/optimizer/placeholder.h | 2 +
src/include/optimizer/prep.h | 8 +
src/test/regress/expected/partition_join.out | 4 +
src/test/regress/expected/sysviews.out | 29 +-
src/test/regress/sql/partition_join.sql | 5 +
22 files changed, 1728 insertions(+), 74 deletions(-)
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 30d733e..72c021e 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2070,6 +2070,15 @@ _copyRestrictInfo(const RestrictInfo *from)
COPY_SCALAR_FIELD(left_bucketsize);
COPY_SCALAR_FIELD(right_bucketsize);
+ /*
+ * Do not copy parent_rinfo and child_rinfos because 1. they create a
+ * circular dependency between child and parent RestrictInfo 2. dropping
+ * those links just means that we loose some memory optimizations. 3. There
+ * is a possibility that the child and parent RestrictInfots themselves may
+ * have got copied and thus the old links may no longer be valid. The
+ * caller may set up those links itself, if needed.
+ */
+
return newnode;
}
diff --git a/src/backend/optimizer/README b/src/backend/optimizer/README
index fc0fca4..7565ae4 100644
--- a/src/backend/optimizer/README
+++ b/src/backend/optimizer/README
@@ -1076,3 +1076,56 @@ be desirable to postpone the Gather stage until as near to the top of the
plan as possible. Expanding the range of cases in which more work can be
pushed below the Gather (and costing them accurately) is likely to keep us
busy for a long time to come.
+
+Partition-wise joins
+--------------------
+A join between two similarly partitioned tables can be broken down into joins
+between their matching partitions if there exists an equi-join condition
+between the partition keys of the joining tables. The equi-join between
+partition keys implies that for a given row in a given partition of a given
+partitioned table, its joining row, if exists, should exist only in the
+matching partition of the other partitioned table; no row from non-matching
+partitions in the other partitioned table can join with the given row from the
+first table. This condition allows the join between partitioned table to be
+broken into joins between the matching partitions. The resultant join is
+partitioned in the same way as the joining relations, thus allowing an N-way
+join between similarly partitioned tables having equi-join condition between
+their partition keys to be broken down into N-way joins between their matching
+partitions. This technique of breaking down a join between partition tables
+into join between their partitions is called partition-wise join. We will use
+term "partitioned relation" for both partitioned table as well as join between
+partitioned tables which can use partition-wise join technique.
+
+Partitioning properties of a partitioned table are stored in
+PartitionSchemeData structure. Planner maintains a list of canonical partition
+schemes (distinct PartitionSchemeData objects) so that any two partitioned
+relations with same partitioning scheme share the same PartitionSchemeData
+object. This reduces memory consumed by PartitionSchemeData objects and makes
+it easy to compare the partition schemes of joining relations. RelOptInfos of
+partitioned relations hold partition key expressions and the RelOptInfos of
+the partition relations of that relation.
+
+Partition-wise joins are planned in two phases
+
+1. First phase creates the RelOptInfos for joins between matching partitions,
+henceforth referred to as child-joins. The number of paths created for a
+child-join i.e. join between partitions is same as the number of paths created
+for join between parents. That number grows exponentially with the number of
+base relations being joined. The time and memory consumed to create paths for
+each child-join will be proporional to the number of partitions. This will not
+scale well with thousands of partitions. Instead of that we estimate
+partition-wise join cost based on the costs of sampled child-joins. We choose
+child-joins with higher sizes to have realistic estimates. If the number of
+sampled child-joins is same as the number of live child-joins, we create append
+paths as we know costs of all required child-joins. Otherwise we create
+PartitionJoinPaths with cost estimates based on the costs of sampled
+child-joins. While creating append paths or PartitionJoin paths we create paths
+for all the different possible parameterizations and pathkeys available in the
+sampled child-joins.
+
+2. If PartitionJoinPath emerges as the best possible path, we create paths for
+each unsampled child-join. From every child-join we choose the cheapest path
+with same parameterization or pathkeys as the PartitionJoinPath. This path is
+converted into a plan and all the child-join plans are combined using an Append
+or MergeAppend plan as appropriate. We use a fresh memory context for planning
+each unsampled child-join, thus reducing memory consumption.
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 0eb56f3..cebf359 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -15,6 +15,7 @@
#include "postgres.h"
+#include "miscadmin.h"
#include <limits.h>
#include <math.h>
@@ -93,11 +94,8 @@ static void set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
static void set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
static void generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels,
- List *all_child_pathkeys);
-static Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
- RelOptInfo *rel,
- Relids required_outer);
+ List *live_childrels, List *all_child_pathkeys,
+ bool partition_join_path);
static List *accumulate_append_subpath(List *subpaths, Path *path);
static void set_subquery_pathlist(PlannerInfo *root, RelOptInfo *rel,
Index rti, RangeTblEntry *rte);
@@ -128,8 +126,8 @@ static void recurse_push_qual(Node *setOp, Query *topquery,
static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel);
static int compute_parallel_worker(RelOptInfo *rel, BlockNumber pages);
static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels);
-
+ List *live_childrels, bool partition_join_path);
+static int compare_rel_size(const void *rel1_p, const void *rel2_p);
/*
* make_one_rel
@@ -891,6 +889,12 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel = find_base_rel(root, childRTindex);
Assert(childrel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ /* Pass top parent's relids down the inheritance hierarchy. */
+ if (rel->top_parent_relids)
+ childrel->top_parent_relids = rel->top_parent_relids;
+ else
+ childrel->top_parent_relids = bms_copy(rel->relids);
+
/*
* Two partitioned tables with the same partitioning scheme, have their
* partition bounds arranged in the same order. The order of partition
@@ -900,10 +904,15 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* RelOptInfos. Arranging RelOptInfos of partitions in the same order
* as their OIDs makes it easy to find the RelOptInfos of matching
* partitions for partition-wise join.
+ *
+ * For a partitioned tables, individual partitions can participate in
+ * the pair-wise joins. We need attr_needed data for building
+ * child-join targetlists.
*/
if (rel->part_scheme)
{
int cnt_parts;
+ AttrNumber attno;
for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
{
@@ -913,6 +922,38 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
rel->part_rels[cnt_parts] = childrel;
}
}
+
+ for (attno = rel->min_attr; attno <= rel->max_attr; attno++)
+ {
+ int index = attno - rel->min_attr;
+ Relids attr_needed = bms_copy(rel->attr_needed[index]);
+
+ /*
+ * System attributes do not need translation. In such a case,
+ * the attribute numbers of the parent and the child should
+ * start from the same minimum attribute.
+ */
+ if (attno <= 0)
+ {
+ Assert(rel->min_attr == childrel->min_attr);
+ childrel->attr_needed[index] = attr_needed;
+ }
+ else
+ {
+ Var *var = list_nth(appinfo->translated_vars,
+ attno - 1);
+ int child_index;
+
+ /*
+ * Parent Var for a user defined attribute translates to
+ * child Var.
+ */
+ Assert(IsA(var, Var));
+
+ child_index = var->varattno - childrel->min_attr;
+ childrel->attr_needed[child_index] = attr_needed;
+ }
+ }
}
/*
@@ -1057,10 +1098,8 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* PlaceHolderVars.) XXX we do not bother to update the cost or width
* fields of childrel->reltarget; not clear if that would be useful.
*/
- childrel->joininfo = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->joininfo,
- appinfo_list);
+ childrel->joininfo = build_child_clauses(root, rel->joininfo,
+ appinfo_list);
childrel->reltarget->exprs = (List *)
adjust_appendrel_attrs(root,
(Node *) rel->reltarget->exprs,
@@ -1079,14 +1118,6 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
childrel->has_eclass_joins = rel->has_eclass_joins;
/*
- * Note: we could compute appropriate attr_needed data for the child's
- * variables, by transforming the parent's attr_needed through the
- * translated_vars mapping. However, currently there's no need
- * because attr_needed is only examined for base relations not
- * otherrels. So we just leave the child's attr_needed empty.
- */
-
- /*
* If parallelism is allowable for this query in general, see whether
* it's allowable for this childrel in particular. But if we've
* already decided the appendrel is not parallel-safe as a whole,
@@ -1269,10 +1300,9 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
/* Add Append/MergeAppend paths to the "append" relation. */
- add_paths_to_append_rel(root, rel, live_childrels);
+ add_paths_to_append_rel(root, rel, live_childrels, false);
}
-
/*
* add_paths_to_append_rel
* Generate Append/MergeAppend paths for given "append" relation.
@@ -1282,20 +1312,44 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* an append path collecting one path from each non-dummy child with given
* parameterization or ordering. Similarly it collects partial paths from
* non-dummy children to create partial append paths.
+ *
+ * When called on partitioned join relation with partition_join_path = true, it
+ * adds PartitionJoinPath instead of Merge/Append path. This path is costed
+ * based on the costs of sampled child-join and is expanded later into
+ * Merge/Append plan.
*/
static void
add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
- List *live_childrels)
+ List *live_childrels, bool partition_join_path)
{
List *subpaths = NIL;
bool subpaths_valid = true;
List *partial_subpaths = NIL;
- bool partial_subpaths_valid = true;
+ bool partial_subpaths_valid;
List *all_child_pathkeys = NIL;
List *all_child_outers = NIL;
ListCell *l;
/*
+ * While creating PartitionJoinPath, we sample paths from only a few child
+ * relations. Even if all of sampled children have partial paths, it's not
+ * guaranteed that all the unsampled children will have partial paths.
+ * Hence we do not create partial PartitionJoinPaths.
+ */
+ partial_subpaths_valid = !partition_join_path ? true : false;
+
+ /* An append relation with all its children dummy is dummy. */
+ if (live_childrels == NIL)
+ {
+ /* Mark the relation as dummy, if not already done so. */
+ if (!IS_DUMMY_REL(rel))
+ set_dummy_rel_pathlist(rel);
+
+ /* No more paths need to be added. */
+ return;
+ }
+
+ /*
* For every non-dummy child, remember the cheapest path. Also, identify
* all pathkeys (orderings) and parameterizations (required_outer sets)
* available for the non-dummy member relations.
@@ -1394,7 +1448,17 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel, subpaths,
+ NULL, NIL);
+ else
+ path = (Path *) create_append_path(rel, subpaths, NULL, 0);
+
+ add_path(rel, path);
+ }
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1405,6 +1469,8 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
ListCell *lc;
int parallel_workers = 0;
+ Assert(!partition_join_path);
+
/*
* Decide on the number of workers to request for this append path.
* For now, we just use the maximum value from among the members. It
@@ -1431,7 +1497,7 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
*/
if (subpaths_valid)
generate_mergeappend_paths(root, rel, live_childrels,
- all_child_pathkeys);
+ all_child_pathkeys, partition_join_path);
/*
* Build Append paths for each parameterization seen among the child rels.
@@ -1472,8 +1538,18 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ {
+ Path *path;
+
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel, subpaths,
+ required_outer, NIL);
+ else
+ path = (Path *) create_append_path(rel, subpaths,
+ required_outer, 0);
+
+ add_path(rel, path);
+ }
}
}
@@ -1499,11 +1575,16 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel,
* parameterized mergejoin plans, it might be worth adding support for
* parameterized MergeAppends to feed such joins. (See notes in
* optimizer/README for why that might not ever happen, though.)
+ *
+ * When called on partitioned join relation with partition_join_path = true, it
+ * adds PartitionJoinPath with pathkeys instead of MergeAppend path. This path
+ * is costed based on the costs of sampled child-join and is expanded later
+ * into MergeAppend plan.
*/
static void
generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *live_childrels,
- List *all_child_pathkeys)
+ List *all_child_pathkeys, bool partition_join_path)
{
ListCell *lcp;
@@ -1514,6 +1595,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
List *total_subpaths = NIL;
bool startup_neq_total = false;
ListCell *lcr;
+ Path *path;
/* Select the child paths for this ordering... */
foreach(lcr, live_childrels)
@@ -1560,18 +1642,29 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
accumulate_append_subpath(total_subpaths, cheapest_total);
}
- /* ... and build the MergeAppend paths */
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- startup_subpaths,
- pathkeys,
- NULL));
+ /* ... and build the paths */
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel,
+ startup_subpaths,
+ NULL, pathkeys);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ startup_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+
if (startup_neq_total)
- add_path(rel, (Path *) create_merge_append_path(root,
- rel,
- total_subpaths,
- pathkeys,
- NULL));
+ {
+ if (partition_join_path)
+ path = (Path *) create_partition_join_path(root, rel,
+ total_subpaths,
+ NULL, pathkeys);
+ else
+ path = (Path *) create_merge_append_path(root, rel,
+ total_subpaths,
+ pathkeys, NULL);
+ add_path(rel, path);
+ }
}
}
@@ -1582,7 +1675,7 @@ generate_mergeappend_paths(PlannerInfo *root, RelOptInfo *rel,
*
* Returns NULL if unable to create such a path.
*/
-static Path *
+Path *
get_cheapest_parameterized_child_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer)
{
@@ -2316,8 +2409,17 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
* Run generate_gather_paths() for each just-processed joinrel. We
* could not do this earlier because both regular and partial paths
* can get added to a particular joinrel at multiple times within
- * join_search_one_level. After that, we're done creating paths for
- * the joinrel, so run set_cheapest().
+ * join_search_one_level.
+ *
+ * Similarly, create paths for joinrels which used partition-wise join
+ * technique. generate_partition_wise_join_paths() creates paths for
+ * only few of the child-joins with highest sizes. Though we calculate
+ * size of a child-join only once; when it gets created, it may be
+ * deemed empty while considering various join orders within
+ * join_search_one_level.
+ *
+ * After that, we're done creating paths for the joinrel, so run
+ * set_cheapest().
*/
foreach(lc, root->join_rel_level[lev])
{
@@ -2326,6 +2428,9 @@ standard_join_search(PlannerInfo *root, int levels_needed, List *initial_rels)
/* Create GatherPaths for any useful partial paths for rel */
generate_gather_paths(root, rel);
+ /* Create paths for partition-wise joins. */
+ generate_partition_wise_join_paths(root, rel);
+
/* Find and save the cheapest paths for this rel */
set_cheapest(rel);
@@ -3011,6 +3116,138 @@ compute_parallel_worker(RelOptInfo *rel, BlockNumber pages)
return parallel_workers;
}
+/*
+ * Function to compare estimated sizes of two relations to be used with
+ * qsort(). Remember that this function is used to sort an array of position
+ * pointers in the array of partitions. So, we have to use double indirection.
+ * See more comments in generate_partition_wise_join_paths() where this
+ * function is used.
+ */
+static int
+compare_rel_size(const void *rel1_p, const void *rel2_p)
+{
+ RelOptInfo *rel1 = **(RelOptInfo ***) rel1_p;
+ RelOptInfo *rel2 = **(RelOptInfo ***) rel2_p;
+
+ return (int) (rel1->rows - rel2->rows);
+}
+
+/*
+ * generate_partition_wise_join_paths
+ *
+ * Create paths representing partition-wise join for given partitioned
+ * join relation.
+ *
+ * The number of paths created for a child-join is same as the number of paths
+ * created for join between parents. That number grows exponentially with the
+ * number of base relations being joined. The time and memory consumed to
+ * create paths for each child-join will be proporional to the number of
+ * partitions. This will not scale well with thousands of partitions. Instead
+ * of that we estimate partition-wise join cost based on the costs of sampled
+ * child-joins. We choose child-joins with higher sizes to have realistic
+ * estimates.
+ *
+ * This must be called after we have considered all joining orders since
+ * certain join orders may allow us to deem a child-join as dummy.
+ */
+void
+generate_partition_wise_join_paths(PlannerInfo *root, RelOptInfo *rel)
+{
+ List *sampled_children = NIL;
+ int cnt_parts;
+ int num_part_to_plan;
+ int num_parts;
+ bool partition_join_path = false;
+ int num_dummy_parts = 0;
+ RelOptInfo ***ordered_part_rels;
+ RelOptInfo **part_rels;
+
+ /* Handle only join relations. */
+ if (!IS_JOIN_REL(rel))
+ return;
+
+ /*
+ * If none of the join orders for this relation could use partition-wise
+ * join technique, the join is not partitioned. Reset the partitioning
+ * scheme.
+ */
+ if (!rel->part_rels)
+ rel->part_scheme = NULL;
+
+ /* If the relation is not partitioned or is proven dummy, nothing to do. */
+ if (!rel->part_scheme || IS_DUMMY_REL(rel))
+ return;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ num_parts = rel->part_scheme->nparts;
+ part_rels = rel->part_rels;
+
+ /* Calculate number of child-joins to sample. */
+ num_part_to_plan = num_parts * sample_partition_fraction;
+ if (num_part_to_plan < 1)
+ num_part_to_plan = 1;
+
+ /* Order the child-join relations by their size.
+ * add_paths_to_child_joinrel() needs the position of the child-join in the
+ * array of partition relations. So instead of sorting the actual relations
+ * get their indexes sorted. We use C pointer arithmatic with qsort to do
+ * this.
+ */
+ ordered_part_rels = (RelOptInfo ***) palloc(sizeof(RelOptInfo **) *
+ num_parts);
+ for (cnt_parts = 0; cnt_parts < num_parts; cnt_parts++)
+ ordered_part_rels[cnt_parts] = &part_rels[cnt_parts];
+ qsort(ordered_part_rels, num_parts, sizeof(ordered_part_rels[0]),
+ compare_rel_size);
+
+ /*
+ * Create paths for the child-joins for required number of largest
+ * relations. qsort() returns relations ordered in ascending sizes, so
+ * start from the end of the array.
+ */
+ for (cnt_parts = num_parts - 1; cnt_parts >= 0; cnt_parts--)
+ {
+ int child_no = ordered_part_rels[cnt_parts] - part_rels;
+ RelOptInfo *child_rel = part_rels[child_no];
+
+ /* Create paths for this child. */
+ add_paths_to_child_joinrel(root, rel, child_no);
+
+ /* Dummy children will not be scanned, so ingore those. */
+ if (IS_DUMMY_REL(child_rel))
+ {
+ num_dummy_parts++;
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ sampled_children = lappend(sampled_children, child_rel);
+
+ if (list_length(sampled_children) >= num_part_to_plan)
+ break;
+ }
+ pfree(ordered_part_rels);
+
+ /*
+ * If the number of samples is same as the number of live children, an
+ * append path will do. Otherwise, we will cost the partition-wise join
+ * based on the sampled children using PartitionJoinPath.
+ */
+ if (num_part_to_plan < num_parts - num_dummy_parts)
+ partition_join_path = true;
+
+ /* Add paths for partition-wise join based on the sampled children. */
+ add_paths_to_append_rel(root, rel, sampled_children, partition_join_path);
+
+ if (sampled_children)
+ list_free(sampled_children);
+}
+
/*****************************************************************************
* DEBUG SUPPORT
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index a43daa7..c720115 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,9 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool enable_partition_wise_join = true;
+double partition_wise_plan_weight = DEFAULT_PARTITION_WISE_PLAN_WEIGHT;
+double sample_partition_fraction = DEFAULT_SAMPLE_PARTITION_FRACTION;
typedef struct
{
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index 2897245..f80fb25 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -96,6 +96,19 @@ add_paths_to_joinrel(PlannerInfo *root,
JoinPathExtraData extra;
bool mergejoin_allowed = true;
ListCell *lc;
+ Relids joinrelids;
+
+ /*
+ * PlannerInfo doesn't contain the SpecialJoinInfos created for joins
+ * between child relations, even if there is a SpecialJoinInfo node for
+ * the join between the topmost parents. Hence while calculating Relids
+ * set representing the restriction, consider relids of topmost parent
+ * of partitions.
+ */
+ if (joinrel->reloptkind == RELOPT_OTHER_JOINREL)
+ joinrelids = joinrel->top_parent_relids;
+ else
+ joinrelids = joinrel->relids;
extra.restrictlist = restrictlist;
extra.mergeclause_list = NIL;
@@ -149,16 +162,16 @@ add_paths_to_joinrel(PlannerInfo *root,
* join has already been proven legal.) If the SJ is relevant, it
* presents constraints for joining to anything not in its RHS.
*/
- if (bms_overlap(joinrel->relids, sjinfo2->min_righthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_lefthand))
+ if (bms_overlap(joinrelids, sjinfo2->min_righthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_lefthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_righthand));
/* full joins constrain both sides symmetrically */
if (sjinfo2->jointype == JOIN_FULL &&
- bms_overlap(joinrel->relids, sjinfo2->min_lefthand) &&
- !bms_overlap(joinrel->relids, sjinfo2->min_righthand))
+ bms_overlap(joinrelids, sjinfo2->min_lefthand) &&
+ !bms_overlap(joinrelids, sjinfo2->min_righthand))
extra.param_source_rels = bms_join(extra.param_source_rels,
bms_difference(root->all_baserels,
sjinfo2->min_lefthand));
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 936ee0c..7476e8e 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -14,9 +14,14 @@
*/
#include "postgres.h"
+#include "miscadmin.h"
+#include "nodes/relation.h"
+#include "optimizer/clauses.h"
#include "optimizer/joininfo.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
+#include "optimizer/prep.h"
+#include "optimizer/cost.h"
#include "utils/memutils.h"
@@ -35,6 +40,14 @@ static bool restriction_is_constant_false(List *restrictlist,
static void populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
RelOptInfo *rel2, RelOptInfo *joinrel,
SpecialJoinInfo *sjinfo, List *restrictlist);
+static void try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1,
+ RelOptInfo *rel2, RelOptInfo *joinrel,
+ SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist);
+static bool have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist);
+static int match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel);
+static void free_special_join_info(SpecialJoinInfo *sjinfo);
/*
@@ -731,6 +744,9 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
populate_joinrel_with_paths(root, rel1, rel2, joinrel, sjinfo,
restrictlist);
+ /* Apply partition-wise join technique, if possible. */
+ try_partition_wise_join(root, rel1, rel2, joinrel, sjinfo, restrictlist);
+
bms_free(joinrelids);
return joinrel;
@@ -1269,3 +1285,408 @@ restriction_is_constant_false(List *restrictlist, bool only_pushed_down)
}
return false;
}
+
+/* Free memory used by SpecialJoinInfo. */
+static void
+free_special_join_info(SpecialJoinInfo *sjinfo)
+{
+ bms_free(sjinfo->min_lefthand);
+ bms_free(sjinfo->syn_lefthand);
+ bms_free(sjinfo->syn_righthand);
+ pfree(sjinfo);
+}
+
+/*
+ * Assess whether join between given two partitioned relations can be broken
+ * down into joins between matching partitions; a technique called
+ * "partition-wise join"
+ *
+ * Partition-wise join is possible when a. Joining relations have same
+ * partitioning scheme b. There exists an equi-join between the partition keys
+ * of the two relations.
+ *
+ * Partition-wise join is planned as follows (details: optimizer/README.)
+ *
+ * 1. Create the RelOptInfos for joins between matching partitions i.e
+ * child-joins and estimate sizes of those. This function is responsible for
+ * this phase.
+ *
+ * 2. Add paths representing partition-wise join. The second phase is
+ * implemented by generate_partition_wise_join_paths(). In order to save time
+ * and memory consumed in creating paths for every child-join, we create paths
+ * for only few child-joins.
+ *
+ * 3. Create merge/append plan to combining plans for every child-join,
+ * creating paths for remaining child-joins.
+ *
+ * The RelOptInfo, SpecialJoinInfo and restrictlist for each child join are
+ * obtained by translating the respective parent join structures.
+ */
+static void
+try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2,
+ RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo,
+ List *parent_restrictlist)
+{
+ int nparts;
+ int cnt_parts;
+ PartitionScheme part_scheme;
+ PartitionedJoin *partitioned_join;
+
+ /* Guard against stack overflow due to overly deep partition hierarchy. */
+ check_stack_depth();
+
+ /* Nothing to do, if the join relation is not partitioned. */
+ if (!joinrel->part_scheme)
+ return;
+
+ /*
+ * If any of the joining parent relations is proven empty, either the join
+ * will be empty (INNER join) or will have the inner side all nullified. We
+ * take care of such cases when creating join paths for parent relations.
+ * Nothing to be done here. Also, nothing to do, if the parent join is
+ * proven empty.
+ */
+ if (IS_DUMMY_REL(rel1) || IS_DUMMY_REL(rel2) || IS_DUMMY_REL(joinrel))
+ return;
+
+ /*
+ * Partitioning scheme in join relation indicates a possibility that the
+ * join may be partitioned, but it's not necessary that every pair of
+ * joining relations can use partition-wise join technique. If one of
+ * joining relations turns out to be unpartitioned, this pair of joining
+ * relations can not use partition-wise join technique.
+ */
+ if (!rel1->part_scheme || !rel2->part_scheme)
+ return;
+
+ /*
+ * If an equi-join condition between the partition keys of the joining
+ * relations does not exist, this pair of joining relations can not use
+ * partition-wise technique.
+ */
+ if (!have_partkey_equi_join(rel1, rel2, parent_sjinfo->jointype,
+ parent_restrictlist))
+ return;
+
+ /*
+ * The partition scheme of the join relation should match that of the
+ * joining relations.
+ */
+ Assert(joinrel->part_scheme == rel1->part_scheme &&
+ joinrel->part_scheme == rel2->part_scheme);
+
+ /* We should have RelOptInfos of the partitions available. */
+ Assert(rel1->part_rels && rel2->part_rels);
+
+ part_scheme = joinrel->part_scheme;
+ nparts = part_scheme->nparts;
+
+ /*
+ * We do not store information about valid pairs of joining child
+ * relations. The pair of joining relations for a child-join can be derived
+ * from valid pairs of joining parent relations. Amongst the valid pairs of
+ * parent joining relations, only those which result in partitioned join
+ * matter for partition-wise join. Remember those so that we can use them
+ * for creating paths for few child-joins in
+ * generate_partition_wise_join_paths() later.
+ */
+ partitioned_join = (PartitionedJoin *) palloc(sizeof(PartitionedJoin));
+ partitioned_join->rel1 = rel1;
+ partitioned_join->rel2 = rel2;
+ partitioned_join->sjinfo = copyObject(parent_sjinfo);
+ partitioned_join->restrictlist = parent_restrictlist;
+ joinrel->partitioned_joins = lappend(joinrel->partitioned_joins,
+ partitioned_join);
+
+ elog(DEBUG3, "join between relations %s and %s is considered for partition-wise join.",
+ bmsToString(rel1->relids), bmsToString(rel2->relids));
+
+ /* We are done if child RelOptInfos are already created. */
+ if (joinrel->part_rels)
+ return;
+
+ /* Create all the child RelOptInfos. */
+ joinrel->part_rels = (RelOptInfo **) palloc0(sizeof(RelOptInfo *) * nparts);
+
+ /*
+ * Create child join relations for this partitioned join. While doing so,
+ * we estimate sizes of these child join relations. These estimates are
+ * used to find the representative child relations used for costing the
+ * partition-wise join later.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts];
+ RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+ RelOptInfo *child_joinrel;
+
+ /* We should never try to join two overlapping sets of rels. */
+ Assert(!bms_overlap(child_rel1->relids, child_rel2->relids));
+
+ Assert (!joinrel->part_rels[cnt_parts]);
+
+ child_joinrel = build_child_join_rel(root, child_rel1, child_rel2,
+ joinrel, parent_sjinfo->jointype);
+
+ joinrel->part_rels[cnt_parts] = child_joinrel;
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, parent_restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, parent_sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+ /*
+ * Set estimates of the child-joinrel's size.
+ */
+ set_joinrel_size_estimates(root, child_joinrel, child_rel1, child_rel2,
+ child_sjinfo, child_restrictlist);
+
+ /*
+ * If the child relations themselves are partitioned, try partition-wise join
+ * recursively.
+ */
+ try_partition_wise_join(root, child_rel1, child_rel2, child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+}
+
+/*
+ * add_paths_to_child_join
+ * Add paths to 'child_id'th child of given parent join relation.
+ *
+ * The function creates paths for given child-join by joining corresponding
+ * children of every pair of joining parent relations which produces
+ * partitioned join. Since we create paths only for sampled child-joins, either
+ * of the children being joined may not have paths. In that case, this function
+ * is called recursively to populate paths for those.
+ */
+void
+add_paths_to_child_joinrel(PlannerInfo *root, RelOptInfo *parent_joinrel,
+ int child_id)
+{
+ ListCell *lc;
+ RelOptInfo *child_joinrel = parent_joinrel->part_rels[child_id];
+
+ Assert(IS_JOIN_REL(parent_joinrel));
+
+ /* If this child relation already has paths, nothing to do. */
+ if (child_joinrel->cheapest_total_path)
+ return;
+
+ /* A dummy relation will have a dummy path as the cheapest path. */
+ Assert(!is_dummy_rel(child_joinrel));
+
+ /*
+ * For every partitioned join order, calculate paths for the joining
+ * child relations and then calculate paths for given child.
+ */
+ foreach (lc, parent_joinrel->partitioned_joins)
+ {
+ PartitionedJoin *pj = lfirst(lc);
+ RelOptInfo *rel1 = pj->rel1;
+ RelOptInfo *rel2 = pj->rel2;
+ RelOptInfo *child_rel1 = rel1->part_rels[child_id];
+ RelOptInfo *child_rel2 = rel2->part_rels[child_id];
+ SpecialJoinInfo *child_sjinfo;
+ List *child_restrictlist;
+
+ /*
+ * Add paths to joining relation if it is a join itself.
+ * Paths for child base relations are created in
+ * set_append_rel_pathlist().
+ */
+ if (IS_JOIN_REL(pj->rel1))
+ add_paths_to_child_joinrel(root, rel1, child_id);
+
+ if (IS_JOIN_REL(pj->rel2))
+ add_paths_to_child_joinrel(root, rel2, child_id);
+
+ /*
+ * Construct SpecialJoinInfo from parent join relations's
+ * SpecialJoinInfo.
+ */
+ child_sjinfo = build_child_join_sjinfo(root, pj->sjinfo,
+ child_rel1->relids,
+ child_rel2->relids);
+
+
+ /*
+ * Construct restrictions applicable to the child join from
+ * those applicable to the parent join.
+ */
+ child_restrictlist = build_child_clauses(root, pj->restrictlist,
+ find_appinfos_by_relids(root,
+ child_joinrel->relids));
+
+ /* Add paths for child join. */
+ populate_joinrel_with_paths(root, rel1->part_rels[child_id],
+ rel2->part_rels[child_id], child_joinrel,
+ child_sjinfo, child_restrictlist);
+
+ /* Add partition-wise join paths for partitioned child-joins. */
+ generate_partition_wise_join_paths(root, child_joinrel);
+
+ free_special_join_info(child_sjinfo);
+ child_sjinfo = NULL;
+ }
+
+ set_cheapest(child_joinrel);
+}
+
+/*
+ * Returns true if there exists an equi-join condition for each pair of
+ * partition key from given relations being joined.
+ */
+static bool
+have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2,
+ JoinType jointype, List *restrictlist)
+{
+ PartitionScheme part_scheme = rel1->part_scheme;
+ ListCell *lc;
+ int cnt_pks;
+ int num_pks;
+ bool *pk_has_clause;
+
+ /*
+ * This function should be called when the joining relations have same
+ * partitioning scheme.
+ */
+ Assert(rel1->part_scheme == rel2->part_scheme);
+ Assert(part_scheme);
+
+ num_pks = part_scheme->partnatts;
+
+ pk_has_clause = (bool *) palloc0(sizeof(bool) * num_pks);
+
+ foreach (lc, restrictlist)
+ {
+ RestrictInfo *rinfo = lfirst(lc);
+ OpExpr *opexpr;
+ Expr *expr1;
+ Expr *expr2;
+ int ipk1;
+ int ipk2;
+
+ /* If processing an outer join, only use its own join clauses. */
+ if (IS_OUTER_JOIN(jointype) && rinfo->is_pushed_down)
+ continue;
+
+ /* Skip clauses which can not be used for a join. */
+ if (!rinfo->can_join)
+ continue;
+
+ /* Skip clauses which are not equality conditions. */
+ if (rinfo->hashjoinoperator == InvalidOid && !rinfo->mergeopfamilies)
+ continue;
+
+ opexpr = (OpExpr *) rinfo->clause;
+ Assert(is_opclause(opexpr));
+
+
+ /* Match the operands to the relation. */
+ if (bms_is_subset(rinfo->left_relids, rel1->relids) &&
+ bms_is_subset(rinfo->right_relids, rel2->relids))
+ {
+ expr1 = linitial(opexpr->args);
+ expr2 = lsecond(opexpr->args);
+ }
+ else if (bms_is_subset(rinfo->left_relids, rel2->relids) &&
+ bms_is_subset(rinfo->right_relids, rel1->relids))
+ {
+ expr1 = lsecond(opexpr->args);
+ expr2 = linitial(opexpr->args);
+ }
+ else
+ continue;
+
+ /* Associate matching clauses with partition keys. */
+ ipk1 = match_expr_to_partition_keys(expr1, rel1);
+ ipk2 = match_expr_to_partition_keys(expr2, rel2);
+
+ /*
+ * If the clause refers to different partition keys from
+ * both relations, it can not be used for partition-wise join.
+ */
+ if (ipk1 != ipk2)
+ continue;
+
+ /*
+ * The clause allows partition-wise join if only it uses the same
+ * operator family as that specified by the partition key.
+ */
+ if (!list_member_oid(rinfo->mergeopfamilies,
+ part_scheme->partopfamily[ipk1]))
+ continue;
+
+ /* Mark the partition key as having an equi-join clause. */
+ pk_has_clause[ipk1] = true;
+ }
+
+ /* Check whether every partition key has an equi-join condition. */
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ if (!pk_has_clause[cnt_pks])
+ {
+ pfree(pk_has_clause);
+ return false;
+ }
+ }
+
+ pfree(pk_has_clause);
+ return true;
+}
+
+/*
+ * Find the partition key from the given relation matching the given
+ * expression. If found, return the index of the partition key, else return -1.
+ */
+static int
+match_expr_to_partition_keys(Expr *expr, RelOptInfo *rel)
+{
+ int cnt_pks;
+ int num_pks;
+
+ /* This function should be called only for partitioned relations. */
+ Assert(rel->part_scheme);
+
+ num_pks = rel->part_scheme->partnatts;
+
+ /*
+ * Remove the relabel decoration. We can assume that there is at most one
+ * RelabelType node; eval_const_expressions() simplifies multiple
+ * RelabelType nodes into one.
+ */
+ if (IsA(expr, RelabelType))
+ expr = (Expr *) ((RelabelType *) expr)->arg;
+
+ for (cnt_pks = 0; cnt_pks < num_pks; cnt_pks++)
+ {
+ List *pkexprs = rel->partexprs[cnt_pks];
+ ListCell *lc;
+
+ foreach(lc, pkexprs)
+ {
+ Expr *pkexpr = lfirst(lc);
+ if (equal(pkexpr, expr))
+ return cnt_pks;
+ }
+ }
+
+ return -1;
+}
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 997bdcf..c1f9da2 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -42,6 +42,7 @@
#include "parser/parse_clause.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
/*
@@ -146,6 +147,8 @@ static CustomScan *create_customscan_plan(PlannerInfo *root,
static NestLoop *create_nestloop_plan(PlannerInfo *root, NestPath *best_path);
static MergeJoin *create_mergejoin_plan(PlannerInfo *root, MergePath *best_path);
static HashJoin *create_hashjoin_plan(PlannerInfo *root, HashPath *best_path);
+static Plan *create_partition_join_plan(PlannerInfo *root,
+ PartitionJoinPath *best_path);
static Node *replace_nestloop_params(PlannerInfo *root, Node *expr);
static Node *replace_nestloop_params_mutator(Node *node, PlannerInfo *root);
static void process_subquery_nestloop_params(PlannerInfo *root,
@@ -369,12 +372,20 @@ create_plan_recurse(PlannerInfo *root, Path *best_path, int flags)
(JoinPath *) best_path);
break;
case T_Append:
- plan = create_append_plan(root,
- (AppendPath *) best_path);
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root,
+ (PartitionJoinPath *)best_path);
+ else
+ plan = create_append_plan(root,
+ (AppendPath *) best_path);
break;
case T_MergeAppend:
- plan = create_merge_append_plan(root,
- (MergeAppendPath *) best_path);
+ if (IsA(best_path, PartitionJoinPath))
+ plan = create_partition_join_plan(root,
+ (PartitionJoinPath *)best_path);
+ else
+ plan = create_merge_append_plan(root,
+ (MergeAppendPath *) best_path);
break;
case T_Result:
if (IsA(best_path, ProjectionPath))
@@ -3982,6 +3993,215 @@ create_hashjoin_plan(PlannerInfo *root,
return join_plan;
}
+/*
+ * create_partition_join_plan
+ * Creates Merge/Append plan consisting of join plans for child-join.
+ *
+ * Returns a Plan node.
+ */
+static Plan *
+create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
+{
+ RelOptInfo *joinrel = best_path->path.parent;
+ int nparts;
+ int cnt_parts;
+ List *child_plans = NIL;
+ List *tlist = build_path_tlist(root, &best_path->path);
+ Plan *plan;
+ MemoryContext child_context;
+ MemoryContext old_context;
+ List *pathkeys = best_path->path.pathkeys;
+ StringInfoData mem_context_name;
+
+ /* The relation should be a partitioned join relation. */
+ Assert(IS_JOIN_REL(joinrel) && joinrel->part_scheme &&
+ joinrel->partitioned_joins);
+
+ nparts = joinrel->part_scheme->nparts;
+
+ /* Create MergeAppend plan when result is expected to be ordered. */
+ if (pathkeys)
+ {
+ MergeAppend *node = makeNode(MergeAppend);
+ plan = &node->plan;
+
+ plan->targetlist = tlist;
+
+ /* Compute sorting info, and adjust MergeAppend's tlist as needed. */
+ (void) prepare_sort_from_pathkeys(plan, pathkeys,
+ best_path->path.parent->relids,
+ NULL,
+ true,
+ &node->numCols,
+ &node->sortColIdx,
+ &node->sortOperators,
+ &node->collations,
+ &node->nullsFirst);
+ }
+ else
+ {
+ Append *node = makeNode(Append);
+ plan = &node->plan;
+ plan->targetlist = tlist;
+ }
+
+ /* Fill costs, so that we can cost Sort node, if required. */
+ copy_generic_path_info(plan, (Path *) best_path);
+
+ /*
+ * Create a new memory context for planning child joins. Since this routine
+ * may be called recursively for tables with subpartitions, we use
+ * a unique context name for every level of partition by using the lowest
+ * relid amongst the base relations being joined.
+ */
+ initStringInfo(&mem_context_name);
+ appendStringInfo(&mem_context_name, "%s_%d", "ChildJoinContext",
+ bms_next_member(joinrel->relids, -1));
+ child_context = AllocSetContextCreate(CurrentMemoryContext,
+ pstrdup(mem_context_name.data),
+ ALLOCSET_DEFAULT_SIZES);
+ pfree(mem_context_name.data);
+ resetStringInfo(&mem_context_name);
+
+ /*
+ * Create a paths for all child joins, one child join at a time. The paths
+ * for every child join are independent i.e. one child does not require
+ * paths created for the other. In order to avoid accumulating memory
+ * consumed while creating paths for every child join, we use a fresh
+ * memory context for every child join.
+ */
+ for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
+ {
+ RelOptInfo *child_join;
+ Path *child_path = NULL;
+ Plan *child_plan;
+ int numsortkeys;
+ AttrNumber *sortColIdx;
+ Oid *sortOperators;
+ Oid *collations;
+ bool *nullsFirst;
+
+ /*
+ * Create paths for the child join in a separate context, so that we
+ * can reuse the memory used by those paths.
+ */
+ old_context = MemoryContextSwitchTo(child_context);
+
+ add_paths_to_child_joinrel(root, joinrel, cnt_parts);
+
+ child_join = joinrel->part_rels[cnt_parts];
+
+
+ /* Skip empty child. */
+ if (IS_DUMMY_REL(child_join))
+ {
+ MemoryContextSwitchTo(old_context);
+ continue;
+ }
+
+#ifdef OPTIMIZER_DEBUG
+ debug_print_rel(root, rel);
+#endif
+
+ if (!PATH_REQ_OUTER(&best_path->path))
+ child_path = get_cheapest_path_for_pathkeys(child_join->pathlist,
+ best_path->path.pathkeys,
+ NULL,
+ TOTAL_COST);
+ else
+ child_path = get_cheapest_parameterized_child_path(root,
+ child_join,
+ PATH_REQ_OUTER(&best_path->path));
+
+ if (!child_path)
+ elog(ERROR, "Could not find a child-join path with required pathkeys or parameterization.");
+
+ MemoryContextSwitchTo(old_context);
+
+ /* Create plan for the current child. */
+ child_plan = create_plan_recurse(root, child_path, CP_EXACT_TLIST);
+
+ if (pathkeys)
+ {
+ MergeAppend *node = (MergeAppend *) plan;
+
+ Assert(IsA(node, MergeAppend));
+
+ /* Compute sorting info, and adjust subplan's tlist as needed */
+ child_plan = prepare_sort_from_pathkeys(child_plan, pathkeys,
+ child_path->parent->relids,
+ node->sortColIdx,
+ false,
+ &numsortkeys,
+ &sortColIdx,
+ &sortOperators,
+ &collations,
+ &nullsFirst);
+
+ /*
+ * Check that we got the same sort key information. We just Assert
+ * that the sortops match, since those depend only on the pathkeys;
+ * but it seems like a good idea to check the sort column numbers
+ * explicitly, to ensure the tlists really do match up.
+ */
+ Assert(numsortkeys == node->numCols);
+ if (memcmp(sortColIdx, node->sortColIdx,
+ numsortkeys * sizeof(AttrNumber)) != 0)
+ elog(ERROR, "MergeAppend child's targetlist doesn't match MergeAppend");
+ Assert(memcmp(sortOperators, node->sortOperators,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(collations, node->collations,
+ numsortkeys * sizeof(Oid)) == 0);
+ Assert(memcmp(nullsFirst, node->nullsFirst,
+ numsortkeys * sizeof(bool)) == 0);
+
+ /* Now, insert a Sort node if subplan isn't sufficiently ordered */
+ if (!pathkeys_contained_in(pathkeys, child_path->pathkeys))
+ {
+ Sort *sort = make_sort(child_plan, numsortkeys,
+ sortColIdx, sortOperators,
+ collations, nullsFirst);
+ label_sort_with_costsize(root, sort, -1.0);
+ child_plan = (Plan *) sort;
+ }
+ }
+
+ child_plans = lappend(child_plans, child_plan);
+
+ /*
+ * Reset the child_join memory context to reclaim the memory consumed
+ * while creating paths.
+ */
+ MemoryContextResetAndDeleteChildren(child_context);
+ }
+
+ /* Destroy the child context as we do not need it anymore. */
+ Assert(CurrentMemoryContext == old_context);
+ MemoryContextDelete(child_context);
+
+ /* Partitioned relation with all empty children gets a dummy path. */
+ Assert(child_plans != NIL);
+
+ if (IsA(plan, MergeAppend))
+ {
+ MergeAppend *node = (MergeAppend *)plan;
+
+ node->mergeplans = child_plans;
+ }
+ else
+ {
+ Append *node = (Append *)plan;
+
+ Assert(IsA(plan, Append));
+ node->appendplans = child_plans;
+ }
+
+ /* Complete rest of the plan. */
+ plan->qual = NIL;
+ plan->lefttree = NULL;
+ plan->righttree = NULL;
+ return plan;
+}
/*****************************************************************************
*
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 6f41979..676204f 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -2179,3 +2179,163 @@ adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
/* Now translate for this child */
return adjust_appendrel_attrs(root, node, list_make1(appinfo));
}
+
+/*
+ * build_child_restrictinfo
+ * Returns a RestrictInfo which is derived from the given RestrictInfo by
+ * applying the parent-child translation specified by the list of
+ * AppendRelInfos.
+ *
+ * The topmost parent's RestrictInfo maintains a list of child RestrictInfos
+ * derived from it. If a suitable RestrictInfo is found in that list, it is
+ * returned as is. If there is no such child RestrictInfo, we translate the given
+ * RestrictInfo using the given list of AppendRelInfos and stick it in the
+ * topmost parent's list before returning it to the caller.
+ */
+RestrictInfo *
+build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
+ List *append_rel_infos)
+{
+ Relids child_required_relids;
+ ListCell *lc;
+ RestrictInfo *parent_rinfo;
+ RestrictInfo *child_rinfo;
+ MemoryContext old_context;
+
+ child_required_relids = adjust_relid_set(rinfo->required_relids,
+ append_rel_infos);
+
+
+ /* Nothing to do, if the clause does not need any translation. */
+ if (bms_equal(child_required_relids, rinfo->required_relids))
+ {
+ bms_free(child_required_relids);
+ return rinfo;
+ }
+
+ /*
+ * Check if we already have the RestrictInfo for the given child in the
+ * topmost parent's RestrictInfo.
+ */
+ parent_rinfo = rinfo->parent_rinfo ? rinfo->parent_rinfo : rinfo;
+ foreach (lc, parent_rinfo->child_rinfos)
+ {
+ child_rinfo = lfirst(lc);
+
+ if (bms_equal(child_rinfo->required_relids, child_required_relids))
+ {
+ bms_free(child_required_relids);
+ return child_rinfo;
+ }
+ }
+
+ /*
+ * We didn't find any child restrictinfo for the given child, translate the
+ * given RestrictInfo and stick it into the parent's list. The clause
+ * expression may get used in plan, so create the child RestrictInfo in the
+ * planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ child_rinfo = (RestrictInfo *) adjust_appendrel_attrs(root, (Node *) rinfo,
+ append_rel_infos);
+ bms_free(child_required_relids);
+ parent_rinfo->child_rinfos = lappend(parent_rinfo->child_rinfos,
+ child_rinfo);
+ child_rinfo->parent_rinfo = parent_rinfo;
+
+ MemoryContextSwitchTo(old_context);
+
+ return child_rinfo;
+}
+
+/*
+ * build_child_clauses
+ * Convenience routine to call build_child_restrictinfo on a list of
+ * clauses.
+ */
+List *
+build_child_clauses(PlannerInfo *root, List *clauses, List *append_rel_infos)
+{
+ List *child_clauses = NIL;
+ ListCell *lc;
+
+ foreach (lc, clauses)
+ {
+ RestrictInfo *parent_rinfo = lfirst(lc);
+ RestrictInfo *child_rinfo;
+
+ Assert(IsA(parent_rinfo, RestrictInfo));
+
+ child_rinfo = build_child_restrictinfo(root, parent_rinfo,
+ append_rel_infos);
+
+ child_clauses = lappend(child_clauses, child_rinfo);
+ }
+
+ return child_clauses;
+}
+
+/*
+ * find_appinfos_by_relids
+ * Find AppendRelInfo structures for all relations specified by relids.
+ */
+List *
+find_appinfos_by_relids(PlannerInfo *root, Relids relids)
+{
+ ListCell *lc;
+ List *appinfo_list = NIL;
+
+ foreach (lc, root->append_rel_list)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ if (bms_is_member(appinfo->child_relid, relids))
+ appinfo_list = lappend(appinfo_list, appinfo);
+ }
+
+ Assert(list_length(appinfo_list) == bms_num_members(relids));
+ return appinfo_list;
+}
+
+/*
+ * Construct the SpecialJoinInfo for a child-join by translating
+ * SpecialJoinInfo for the join between parents. left_relids and right_relids
+ * are the relids of left and right side of the join respectively.
+ */
+SpecialJoinInfo *
+build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids)
+{
+ SpecialJoinInfo *sjinfo = makeNode(SpecialJoinInfo);
+ MemoryContext old_context;
+ List *left_appinfos = find_appinfos_by_relids(root, left_relids);
+ List *right_appinfos = find_appinfos_by_relids(root, right_relids);
+
+ memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
+
+ sjinfo->min_lefthand = adjust_relid_set(sjinfo->min_lefthand,
+ left_appinfos);
+ sjinfo->min_righthand = adjust_relid_set(sjinfo->min_righthand,
+ right_appinfos);
+ sjinfo->syn_lefthand = adjust_relid_set(sjinfo->syn_lefthand,
+ left_appinfos);
+ sjinfo->syn_righthand = adjust_relid_set(sjinfo->syn_righthand,
+ right_appinfos);
+
+ /*
+ * Replace the Var nodes of parent with those of children in expressions.
+ * This function may be called within a temporary context, but the
+ * expressions will be shallow-copied into the plan. Hence copy those in
+ * the planner's context.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ sjinfo->semi_rhs_exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) sjinfo->semi_rhs_exprs,
+ right_appinfos);
+ MemoryContextSwitchTo(old_context);
+
+ list_free(left_appinfos);
+ list_free(right_appinfos);
+
+ return sjinfo;
+}
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index f440875..d861a49 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -23,7 +23,9 @@
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
+#include "optimizer/tlist.h"
#include "optimizer/var.h"
#include "parser/parsetree.h"
#include "utils/lsyscache.h"
@@ -2154,6 +2156,117 @@ create_hashjoin_path(PlannerInfo *root,
}
/*
+ * create_partition_join_path
+ * Creates a pathnode that represents partition-wise join for given
+ * partitioned join relation.
+ *
+ * This function is called when we haven't created paths for all the child
+ * joins. It estimates the number of rows and cost of the PartitionJoinPath
+ * based upon the number of rows and the cost of representative child-joins
+ * paths.
+ */
+PartitionJoinPath *
+create_partition_join_path(PlannerInfo *root, RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer, List *pathkeys)
+{
+ PartitionJoinPath *pathnode = makeNode(PartitionJoinPath);
+ double subpath_rows = 0;
+ double subpath_startup_cost = 0;
+ double subpath_total_cost = 0;
+ double child_rel_rows = 0;
+ ListCell *lc;
+
+ Assert(rel->part_scheme);
+
+ pathnode->path.pathtype = pathkeys ? T_MergeAppend : T_Append;
+ pathnode->path.parent = rel;
+ pathnode->path.pathtarget = rel->reltarget;
+ pathnode->path.param_info = get_appendrel_parampathinfo(rel,
+ required_outer);
+ pathnode->path.pathkeys = pathkeys;
+
+ /* No parallel paths here. See more details in add_paths_to_append_rel() */
+ pathnode->path.parallel_aware = false;
+ pathnode->path.parallel_safe = false;
+ pathnode->path.parallel_workers = 0;
+
+ /* Accumulate the number of rows and costs from the given subpaths. */
+ foreach (lc, subpaths)
+ {
+ Path *subpath = lfirst(lc);
+
+ if (!pathkeys)
+ {
+ /*
+ * Startup cost of an append relation is the startup cost of the
+ * first subpath. Assume that the given first child will be the
+ * first child in the final plan as well.
+ */
+ if (lc == list_head(subpaths))
+ subpath_startup_cost = subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else if (pathkeys_contained_in(pathkeys, subpath->pathkeys))
+ {
+ /*
+ * Subpath is adequately ordered, we won't need to sort it. We need
+ * all the subplans to return their respective first rows, before
+ * returning a row. So add the startup costs.
+ */
+ subpath_startup_cost += subpath->startup_cost;
+ subpath_total_cost += subpath->total_cost;
+ }
+ else
+ {
+ /* We'll need to insert a Sort node, so include cost for that */
+ Path sort_path; /* dummy for result of cost_sort */
+
+ cost_sort(&sort_path,
+ root,
+ pathkeys,
+ subpath->total_cost,
+ subpath->parent->tuples,
+ subpath->pathtarget->width,
+ 0.0,
+ work_mem,
+ -1);
+ subpath_startup_cost += sort_path.startup_cost;
+ subpath_total_cost += sort_path.total_cost;
+ }
+
+ subpath_rows += subpath->rows;
+ child_rel_rows += subpath->parent->rows;
+
+ }
+
+ /*
+ * For a parameterized path, extrapolate the number of rows for the append
+ * relation by considering the average selectivity of the parameterization
+ * across the given children.
+ */
+ if (bms_is_empty(required_outer))
+ pathnode->path.rows = rel->rows;
+ else
+ pathnode->path.rows = rel->rows * (subpath_rows / child_rel_rows);
+
+ /* Extrapolate the total cost to account for yet-to-be planned children. */
+ if (!pathkeys)
+ pathnode->path.startup_cost = subpath_startup_cost;
+ else
+ pathnode->path.startup_cost = (subpath_startup_cost * pathnode->path.rows) / subpath_rows;
+ pathnode->path.total_cost = (subpath_total_cost * pathnode->path.rows) / subpath_rows;
+
+ /*
+ * Multiply the costs with scaling factor as specified. Used to encourage
+ * or discourage use of partition-wise join plans.
+ */
+ pathnode->path.startup_cost *= partition_wise_plan_weight;
+ pathnode->path.total_cost *= partition_wise_plan_weight;
+
+ return pathnode;
+}
+
+/*
* create_projection_path
* Creates a pathnode that represents performing a projection.
*
diff --git a/src/backend/optimizer/util/placeholder.c b/src/backend/optimizer/util/placeholder.c
index 698a387..e06bccc 100644
--- a/src/backend/optimizer/util/placeholder.c
+++ b/src/backend/optimizer/util/placeholder.c
@@ -20,6 +20,7 @@
#include "optimizer/pathnode.h"
#include "optimizer/placeholder.h"
#include "optimizer/planmain.h"
+#include "optimizer/prep.h"
#include "optimizer/var.h"
#include "utils/lsyscache.h"
@@ -414,6 +415,10 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
Relids relids = joinrel->relids;
ListCell *lc;
+ /* This function is called only on the parent relations. */
+ Assert(!IS_OTHER_REL(joinrel) && !IS_OTHER_REL(outer_rel) &&
+ !IS_OTHER_REL(inner_rel));
+
foreach(lc, root->placeholder_list)
{
PlaceHolderInfo *phinfo = (PlaceHolderInfo *) lfirst(lc);
@@ -459,3 +464,53 @@ add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
}
}
}
+
+/*
+ * add_placeholders_to_child_joinrel
+ * Translate the PHVs in parent's targetlist and add them to the child's
+ * targetlist. Also adjust the cost
+ */
+void
+add_placeholders_to_child_joinrel(PlannerInfo *root, RelOptInfo *childrel,
+ RelOptInfo *parentrel)
+{
+ ListCell *lc;
+
+ /* This function is called only for join relations. */
+ Assert(IS_JOIN_REL(childrel) && IS_JOIN_REL(parentrel));
+
+ /* Ensure child relations is really what it claims to be. */
+ Assert(IS_OTHER_REL(childrel));
+
+ foreach (lc, parentrel->reltarget->exprs)
+ {
+ PlaceHolderVar *phv = lfirst(lc);
+
+ if (IsA(phv, PlaceHolderVar))
+ {
+ /*
+ * In case the placeholder Var refers to any of the parent
+ * relations, translate it to refer to the corresponding child.
+ */
+ if (bms_overlap(phv->phrels, parentrel->relids) &&
+ childrel->reloptkind == RELOPT_OTHER_JOINREL)
+ {
+ List *append_rel_infos;
+
+ append_rel_infos = find_appinfos_by_relids(root,
+ childrel->relids);
+ phv = (PlaceHolderVar *) adjust_appendrel_attrs(root,
+ (Node *) phv,
+ append_rel_infos);
+ }
+
+ childrel->reltarget->exprs = lappend(childrel->reltarget->exprs,
+ phv);
+ }
+ }
+
+ /* Adjust the cost and width of child targetlist. */
+ childrel->reltarget->cost.startup = parentrel->reltarget->cost.startup;
+ childrel->reltarget->cost.per_tuple = parentrel->reltarget->cost.per_tuple;
+ childrel->reltarget->width = parentrel->reltarget->width;
+}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 19982dc..1eed987 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -23,6 +23,7 @@
#include "optimizer/paths.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
+#include "optimizer/prep.h"
#include "optimizer/restrictinfo.h"
#include "optimizer/tlist.h"
#include "utils/hsearch.h"
@@ -54,6 +55,9 @@ static void set_foreign_rel_properties(RelOptInfo *joinrel,
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
Relids required_outer);
+static void build_joinrel_partition_info(RelOptInfo *joinrel,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ JoinType jointype);
/*
@@ -434,6 +438,9 @@ build_join_rel(PlannerInfo *root,
RelOptInfo *joinrel;
List *restrictlist;
+ /* This function should be used only for join between parents. */
+ Assert(!IS_OTHER_REL(outer_rel) && !IS_OTHER_REL(inner_rel));
+
/*
* See if we already have a joinrel for this set of base rels.
*/
@@ -532,6 +539,10 @@ build_join_rel(PlannerInfo *root,
if (bms_is_empty(joinrel->direct_lateral_relids))
joinrel->direct_lateral_relids = NULL;
+ /* Store the partition information. */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel,
+ sjinfo->jointype);
+
/*
* Construct restrict and join clause lists for the new joinrel. (The
* caller might or might not need the restrictlist, but I need it anyway
@@ -594,6 +605,126 @@ build_join_rel(PlannerInfo *root,
return joinrel;
}
+ /*
+ * build_child_join_rel
+ * Builds RelOptInfo for joining given two child relations from RelOptInfo
+ * representing the join between their parents.
+ *
+ * 'outer_rel' and 'inner_rel' are the RelOptInfos of child relations being
+ * joined.
+ * 'parent_joinrel' is the RelOptInfo representing the join between parent
+ * relations. Most of the members of new RelOptInfo are produced by
+ * translating corresponding members of this RelOptInfo.
+ * 'sjinfo': context info for child join
+ * 'restrictlist': list of RestrictInfo nodes that apply to this particular
+ * pair of joinable relations.
+ * 'join_appinfos': list of AppendRelInfo nodes for base child relations involved
+ * in this join.
+ */
+RelOptInfo *
+build_child_join_rel(PlannerInfo *root, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, RelOptInfo *parent_joinrel,
+ JoinType jointype)
+{
+ RelOptInfo *joinrel = makeNode(RelOptInfo);
+
+ /* Only joins between other relations land here. */
+ Assert(IS_OTHER_REL(outer_rel) && IS_OTHER_REL(inner_rel));
+
+ joinrel->reloptkind = RELOPT_OTHER_JOINREL;
+ joinrel->relids = bms_union(outer_rel->relids, inner_rel->relids);
+ joinrel->rows = 0;
+ /* cheap startup cost is interesting iff not all tuples to be retrieved */
+ joinrel->consider_startup = (root->tuple_fraction > 0);
+ joinrel->consider_param_startup = false;
+ joinrel->consider_parallel = false;
+ joinrel->reltarget = create_empty_pathtarget();
+ joinrel->pathlist = NIL;
+ joinrel->ppilist = NIL;
+ joinrel->partial_pathlist = NIL;
+ joinrel->cheapest_startup_path = NULL;
+ joinrel->cheapest_total_path = NULL;
+ joinrel->cheapest_unique_path = NULL;
+ joinrel->cheapest_parameterized_paths = NIL;
+ joinrel->direct_lateral_relids = NULL;
+ joinrel->lateral_relids = NULL;
+ joinrel->relid = 0; /* indicates not a baserel */
+ joinrel->rtekind = RTE_JOIN;
+ joinrel->min_attr = 0;
+ joinrel->max_attr = 0;
+ joinrel->attr_needed = NULL;
+ joinrel->attr_widths = NULL;
+ joinrel->lateral_vars = NIL;
+ joinrel->lateral_referencers = NULL;
+ joinrel->indexlist = NIL;
+ joinrel->pages = 0;
+ joinrel->tuples = 0;
+ joinrel->allvisfrac = 0;
+ joinrel->subroot = NULL;
+ joinrel->subplan_params = NIL;
+ joinrel->serverid = InvalidOid;
+ joinrel->userid = InvalidOid;
+ joinrel->useridiscurrent = false;
+ joinrel->fdwroutine = NULL;
+ joinrel->fdw_private = NULL;
+ joinrel->baserestrictinfo = NIL;
+ joinrel->baserestrictcost.startup = 0;
+ joinrel->baserestrictcost.per_tuple = 0;
+ joinrel->joininfo = NIL;
+ joinrel->has_eclass_joins = false;
+ joinrel->part_scheme = NULL;
+ joinrel->partexprs = NULL;
+ joinrel->top_parent_relids = NULL;
+ joinrel->part_rels = NULL;
+
+ joinrel->top_parent_relids = bms_union(outer_rel->top_parent_relids,
+ inner_rel->top_parent_relids);
+
+ /* Compute information relevant to foreign relations. */
+ set_foreign_rel_properties(joinrel, outer_rel, inner_rel);
+
+ /* Build targetlist */
+ build_joinrel_tlist(root, joinrel, outer_rel);
+ build_joinrel_tlist(root, joinrel, inner_rel);
+ /* Add placeholder variables. */
+ add_placeholders_to_child_joinrel(root, joinrel, parent_joinrel);
+
+ /* Construct joininfo list. */
+ joinrel->joininfo = build_child_clauses(root, parent_joinrel->joininfo,
+ find_appinfos_by_relids(root,
+ joinrel->relids));
+
+ /*
+ * Lateral relids referred in child join will be same as that referred in
+ * the parent relation. Throw any partial result computed while building
+ * the targetlist.
+ */
+ bms_free(joinrel->direct_lateral_relids);
+ bms_free(joinrel->lateral_relids);
+ joinrel->direct_lateral_relids = (Relids) bms_copy(parent_joinrel->direct_lateral_relids);
+ joinrel->lateral_relids = (Relids) bms_copy(parent_joinrel->lateral_relids);
+
+ /*
+ * If the parent joinrel has pending equivalence classes, so does the
+ * child.
+ */
+ joinrel->has_eclass_joins = parent_joinrel->has_eclass_joins;
+
+ /* Is the join between partitions itself partitioned? */
+ build_joinrel_partition_info(joinrel, outer_rel, inner_rel, jointype);
+
+ /* Child joinrel is parallel safe if parent is parallel safe. */
+ joinrel->consider_parallel = parent_joinrel->consider_parallel;
+
+ /* We build the join only once. */
+ Assert(!find_join_rel(root, joinrel->relids));
+
+ /* Add the relation to the PlannerInfo. */
+ add_join_rel(root, joinrel);
+
+ return joinrel;
+}
+
/*
* min_join_parameterization
*
@@ -649,9 +780,15 @@ static void
build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *input_rel)
{
- Relids relids = joinrel->relids;
+ Relids relids;
ListCell *vars;
+ /* attrs_needed refers to parent relids and not those of a child. */
+ if (joinrel->top_parent_relids)
+ relids = joinrel->top_parent_relids;
+ else
+ relids = joinrel->relids;
+
foreach(vars, input_rel->reltarget->exprs)
{
Var *var = (Var *) lfirst(vars);
@@ -667,23 +804,47 @@ build_joinrel_tlist(PlannerInfo *root, RelOptInfo *joinrel,
/*
* Otherwise, anything in a baserel or joinrel targetlist ought to be
- * a Var. (More general cases can only appear in appendrel child
- * rels, which will never be seen here.)
+ * a Var or ConvertRowtypeExpr introduced while translating parent
+ * targetlist to that of the child.
*/
- if (!IsA(var, Var))
+ if (IsA(var, Var))
+ {
+ /* Get the Var's original base rel */
+ baserel = find_base_rel(root, var->varno);
+
+ /* Is it still needed above this joinrel? */
+ ndx = var->varattno - baserel->min_attr;
+ }
+ else if (IsA(var, ConvertRowtypeExpr))
+ {
+ ConvertRowtypeExpr *child_expr = (ConvertRowtypeExpr *) var;
+ Var *childvar = (Var *) child_expr->arg;
+
+ /*
+ * Child's whole-row references are converted to that of parent
+ * using ConvertRowtypeExpr. In this case, the argument to
+ * ConvertRowtypeExpr is expected to be a whole-row reference of
+ * the child.
+ */
+ Assert(IsA(childvar, Var) && childvar->varattno == 0);
+
+ baserel = find_base_rel(root, childvar->varno);
+ ndx = 0 - baserel->min_attr;
+ }
+ else
elog(ERROR, "unexpected node type in rel targetlist: %d",
(int) nodeTag(var));
- /* Get the Var's original base rel */
- baserel = find_base_rel(root, var->varno);
-
- /* Is it still needed above this joinrel? */
- ndx = var->varattno - baserel->min_attr;
if (bms_nonempty_difference(baserel->attr_needed[ndx], relids))
{
/* Yup, add it to the output */
joinrel->reltarget->exprs = lappend(joinrel->reltarget->exprs, var);
- /* Vars have cost zero, so no need to adjust reltarget->cost */
+
+ /*
+ * Vars have cost zero, so no need to adjust reltarget->cost. Even
+ * if, it's a ConvertRowtypeExpr, it will be computed only for the
+ * base relation, costing nothing for a join.
+ */
joinrel->reltarget->width += baserel->attr_widths[ndx];
}
}
@@ -820,6 +981,9 @@ subbuild_joinrel_joinlist(RelOptInfo *joinrel,
{
ListCell *l;
+ /* Expected to be called only for join between parent relations. */
+ Assert(joinrel->reloptkind == RELOPT_JOINREL);
+
foreach(l, joininfo_list)
{
RestrictInfo *rinfo = (RestrictInfo *) lfirst(l);
@@ -1366,3 +1530,85 @@ find_param_path_info(RelOptInfo *rel, Relids required_outer)
return NULL;
}
+
+/*
+ * build_joinrel_partition_info
+ * If the join between given partitioned relations is possibly partitioned
+ * set the partitioning scheme and partition keys expressions for the
+ * join.
+ *
+ * If the two relations have same partitioning scheme, their join may be
+ * partitioned and will follow the same partitioning scheme as the joining
+ * relations.
+ */
+static void
+build_joinrel_partition_info(RelOptInfo *joinrel, RelOptInfo *outer_rel,
+ RelOptInfo *inner_rel, JoinType jointype)
+{
+ int num_pks;
+ int cnt;
+
+ /* Nothing to do if partition-wise join technique is disabled. */
+ if (!enable_partition_wise_join)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * The join is not partitioned, if any of the relations being joined are
+ * not partitioned or they do not have same partitioning scheme.
+ */
+ if (!outer_rel->part_scheme || !inner_rel->part_scheme ||
+ outer_rel->part_scheme != inner_rel->part_scheme)
+ {
+ joinrel->part_scheme = NULL;
+ return;
+ }
+
+ /*
+ * This function will be called only once for each joinrel, hence it should
+ * not have partition scheme, partition key expressions and array for
+ * storing child relations set.
+ */
+ Assert(!joinrel->part_scheme && !joinrel->partexprs &&
+ !joinrel->part_rels);
+
+ /*
+ * Join relation is partitioned using same partitioning scheme as the
+ * joining relations.
+ */
+ joinrel->part_scheme = outer_rel->part_scheme;
+ num_pks = joinrel->part_scheme->partnatts;
+
+ /*
+ * Construct partition keys for the join.
+ *
+ * An INNER join between two partitioned relations is partition by key
+ * expressions from both the relations. For tables A and B partitioned by a and b
+ * respectively, (A INNER JOIN B ON A.a = B.b) is partitioned by both A.a
+ * and B.b.
+ *
+ * An OUTER join like (A LEFT JOIN B ON A.a = B.b) may produce rows with
+ * B.b NULL. These rows may not fit the partitioning conditions imposed on
+ * B.b. Hence, strictly speaking, the join is not partitioned by B.b.
+ * Strictly speaking, partition keys of an OUTER join should include
+ * partition key expressions from the OUTER side only. Consider a join like
+ * (A LEFT JOIN B on (A.a = B.b) LEFT JOIN C ON B.b = C.c. If we do not
+ * include B.b as partition key expression for (AB), it prohibits us from
+ * using partition-wise join when joining (AB) with C as there is no
+ * equi-join between partition keys of joining relations. But two NULL
+ * values are never equal and no two rows from mis-matching partitions can
+ * join. Hence it's safe to include B.b as partition key expression for
+ * (AB), even though rows in (AB) are not strictly partitioned by B.b.
+ */
+ joinrel->partexprs = (List **) palloc0(sizeof(List *) * num_pks);
+ for (cnt = 0; cnt < num_pks; cnt++)
+ {
+ List *pkexpr = list_copy(outer_rel->partexprs[cnt]);
+
+ pkexpr = list_concat(pkexpr,
+ list_copy(inner_rel->partexprs[cnt]));
+ joinrel->partexprs[cnt] = pkexpr;
+ }
+}
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index de85eca..afd0c23 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -901,6 +901,15 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+ {
+ {"enable_partition_wise_join", PGC_USERSET, QUERY_TUNING_METHOD,
+ gettext_noop("Enables partition-wise join."),
+ NULL
+ },
+ &enable_partition_wise_join,
+ true,
+ NULL, NULL, NULL
+ },
{
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
@@ -2947,6 +2956,25 @@ static struct config_real ConfigureNamesReal[] =
},
{
+ {"partition_wise_plan_weight", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Multiplication factor for partition-wise plan costs."),
+ NULL
+ },
+ &partition_wise_plan_weight,
+ DEFAULT_PARTITION_WISE_PLAN_WEIGHT, 0, DBL_MAX,
+ NULL, NULL, NULL
+ },
+ {
+ {"sample_partition_fraction", PGC_USERSET, QUERY_TUNING_OTHER,
+ gettext_noop("Fraction of partitions to be used as sample for calculating total cost of partition-wise plans."),
+ NULL
+ },
+ &sample_partition_fraction,
+ DEFAULT_SAMPLE_PARTITION_FRACTION, 0, 1,
+ NULL, NULL, NULL
+ },
+
+ {
{"bgwriter_lru_multiplier", PGC_SIGHUP, RESOURCES_BGWRITER,
gettext_noop("Multiple of the average buffer usage to free per round."),
NULL
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 95dd8ba..292d9a6 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -240,6 +240,7 @@ typedef enum NodeTag
T_NestPath,
T_MergePath,
T_HashPath,
+ T_PartitionJoinPath,
T_AppendPath,
T_MergeAppendPath,
T_ResultPath,
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 4f99184..146d53b 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -391,6 +391,11 @@ typedef struct PartitionSchemeData *PartitionScheme;
* handling join alias Vars. Currently this is not needed because all join
* alias Vars are expanded to non-aliased form during preprocess_expression.
*
+ * We also have relations representing joins between child relations of
+ * different partitioned tables. These relations are not added to
+ * join_rel_level lists as they are not joined directly by the dynamic
+ * programming algorithm.
+ *
* There is also a RelOptKind for "upper" relations, which are RelOptInfos
* that describe post-scan/join processing steps, such as aggregation.
* Many of the fields in these RelOptInfos are meaningless, but their Path
@@ -512,10 +517,19 @@ typedef enum RelOptKind
RELOPT_BASEREL,
RELOPT_JOINREL,
RELOPT_OTHER_MEMBER_REL,
+ RELOPT_OTHER_JOINREL,
RELOPT_UPPER_REL,
RELOPT_DEADREL
} RelOptKind;
+#define IS_OTHER_REL(rel) \
+ ((rel)->reloptkind == RELOPT_OTHER_MEMBER_REL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
+#define IS_JOIN_REL(rel) \
+ ((rel)->reloptkind == RELOPT_JOINREL || \
+ (rel)->reloptkind == RELOPT_OTHER_JOINREL)
+
typedef struct RelOptInfo
{
NodeTag type;
@@ -600,6 +614,14 @@ typedef struct RelOptInfo
* as the number of joining
* relations.
*/
+
+ /* For joins between partitioned tables. */
+ List *partitioned_joins; /* List of join orders which yield
+ * relations partitioned by above
+ * partition scheme.
+ */
+ /* Set only for "other" base or "other" join relations. */
+ Relids top_parent_relids; /* Relids of topmost parents. */
} RelOptInfo;
/*
@@ -1540,6 +1562,14 @@ typedef struct LimitPath
Node *limitCount; /* COUNT parameter, or NULL if none */
} LimitPath;
+/*
+ * PartitionJoinPath represents partition-wise join between two partitioned
+ * tables.
+ */
+typedef struct PartitionJoinPath
+{
+ Path path;
+} PartitionJoinPath;
/*
* Restriction clause info.
@@ -1747,6 +1777,18 @@ typedef struct RestrictInfo
/* cache space for hashclause processing; -1 if not yet set */
Selectivity left_bucketsize; /* avg bucketsize of left side */
Selectivity right_bucketsize; /* avg bucketsize of right side */
+
+ /*
+ * Repository to locate child RestrictInfos derived from parent
+ * RestrictInfo. Every derived child RestrictInfo points to the parent
+ * RestrictInfo from which it is derived. Parent RestrictInfo maintains a
+ * list of all derived child RestrictInfos. So only one of the following
+ * should be set.
+ */
+ List *child_rinfos; /* RestrictInfos derived for children. */
+ struct RestrictInfo *parent_rinfo; /* Parent restrictinfo this
+ * RestrictInf is derived from.
+ */
} RestrictInfo;
/*
@@ -1869,6 +1911,21 @@ typedef struct SpecialJoinInfo
} SpecialJoinInfo;
/*
+ * Partitioned join information
+ *
+ * Saves information about relations which can be joined partition-wise and
+ * thus produce result which is partitioned by the partition scheme of the
+ * relation.
+ */
+typedef struct PartitionedJoin
+{
+ RelOptInfo *rel1;
+ RelOptInfo *rel2;
+ SpecialJoinInfo *sjinfo; /* SpecialJoinInfo applicable. */
+ List *restrictlist; /* applicable join clauses. */
+} PartitionedJoin;
+
+/*
* Append-relation info.
*
* When we expand an inheritable table or a UNION-ALL subselect into an
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 0e68264..a13eff1 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -30,6 +30,8 @@
#define DEFAULT_PARALLEL_SETUP_COST 1000.0
#define DEFAULT_EFFECTIVE_CACHE_SIZE 524288 /* measured in pages */
+#define DEFAULT_PARTITION_WISE_PLAN_WEIGHT 1
+#define DEFAULT_SAMPLE_PARTITION_FRACTION 0.01
typedef enum
{
@@ -66,7 +68,10 @@ extern bool enable_nestloop;
extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
+extern bool enable_partition_wise_join;
extern int constraint_exclusion;
+extern double partition_wise_plan_weight;
+extern double sample_partition_fraction;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 7b41317..81d637a 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -229,6 +229,9 @@ extern LimitPath *create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est);
+extern PartitionJoinPath *create_partition_join_path(PlannerInfo *root,
+ RelOptInfo *rel, List *subpaths,
+ Bitmapset *required_outer, List *pathkeys);
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
@@ -271,5 +274,8 @@ extern ParamPathInfo *get_joinrel_parampathinfo(PlannerInfo *root,
List **restrict_clauses);
extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
Relids required_outer);
+extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
+ RelOptInfo *outer_rel, RelOptInfo *inner_rel,
+ RelOptInfo *parent_joinrel, JoinType jointype);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index 81a9be7..821fe36 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -53,6 +53,10 @@ extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
extern void generate_gather_paths(PlannerInfo *root, RelOptInfo *rel);
+extern void generate_partition_wise_join_paths(PlannerInfo *root,
+ RelOptInfo *rel);
+extern Path *get_cheapest_parameterized_child_path(PlannerInfo *root,
+ RelOptInfo *rel, Relids required_outer);
#ifdef OPTIMIZER_DEBUG
extern void debug_print_rel(PlannerInfo *root, RelOptInfo *rel);
@@ -106,6 +110,9 @@ extern bool have_join_order_restriction(PlannerInfo *root,
RelOptInfo *rel1, RelOptInfo *rel2);
extern bool have_dangerous_phv(PlannerInfo *root,
Relids outer_relids, Relids inner_params);
+extern void add_paths_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *parent_joinrel,
+ int child_id);
/*
* equivclass.c
diff --git a/src/include/optimizer/placeholder.h b/src/include/optimizer/placeholder.h
index 11e6403..8598268 100644
--- a/src/include/optimizer/placeholder.h
+++ b/src/include/optimizer/placeholder.h
@@ -28,5 +28,7 @@ extern void fix_placeholder_input_needed_levels(PlannerInfo *root);
extern void add_placeholders_to_base_rels(PlannerInfo *root);
extern void add_placeholders_to_joinrel(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
+extern void add_placeholders_to_child_joinrel(PlannerInfo *root,
+ RelOptInfo *childrel, RelOptInfo *parentrel);
#endif /* PLACEHOLDER_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index a02e06a..5832130 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -57,5 +57,13 @@ extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node,
extern Node *adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel);
+extern RestrictInfo *build_child_restrictinfo(PlannerInfo *root,
+ RestrictInfo *rinfo, List *append_rel_infos);
+extern List *build_child_clauses(PlannerInfo *root, List *clauses,
+ List *append_rel_infos);
+extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
+extern SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
+ SpecialJoinInfo *parent_sjinfo,
+ Relids left_relids, Relids right_relids);
#endif /* PREP_H */
diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out
index 18238fa..79779d6 100644
--- a/src/test/regress/expected/partition_join.out
+++ b/src/test/regress/expected/partition_join.out
@@ -2,6 +2,10 @@
-- PARTITION_JOIN
-- Test partition-wise join between partitioned tables
--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
--
-- partitioned by a single column
--
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index d48abd7..c6c1405 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -70,20 +70,21 @@ select count(*) >= 0 as ok from pg_prepared_xacts;
-- This is to record the prevailing planner enable_foo settings during
-- a regression test run.
select name, setting from pg_settings where name like 'enable%';
- name | setting
-----------------------+---------
- enable_bitmapscan | on
- enable_hashagg | on
- enable_hashjoin | on
- enable_indexonlyscan | on
- enable_indexscan | on
- enable_material | on
- enable_mergejoin | on
- enable_nestloop | on
- enable_seqscan | on
- enable_sort | on
- enable_tidscan | on
-(11 rows)
+ name | setting
+----------------------------+---------
+ enable_bitmapscan | on
+ enable_hashagg | on
+ enable_hashjoin | on
+ enable_indexonlyscan | on
+ enable_indexscan | on
+ enable_material | on
+ enable_mergejoin | on
+ enable_nestloop | on
+ enable_partition_wise_join | on
+ enable_seqscan | on
+ enable_sort | on
+ enable_tidscan | on
+(12 rows)
-- Test that the pg_timezone_names and pg_timezone_abbrevs views are
-- more-or-less working. We can't test their contents in any great detail
diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql
index 0322f1e..9b2baeb 100644
--- a/src/test/regress/sql/partition_join.sql
+++ b/src/test/regress/sql/partition_join.sql
@@ -3,6 +3,11 @@
-- Test partition-wise join between partitioned tables
--
+-- Usually partition-wise join paths are chosen when data is large, which would
+-- take regression tests to run longer. So, weigh partition-wise joins cheaper
+-- to force those even for smaller data.
+SET partition_wise_plan_weight to 0.2;
+
--
-- partitioned by a single column
--
--
1.7.9.5
0009-Adjust-join-related-to-code-to-accept-child-relation.patchapplication/octet-stream; name=0009-Adjust-join-related-to-code-to-accept-child-relation.patchDownload
From 92d2901e80ca783ad9a7a9e0fda24684e7433409 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 17:16:46 +0530
Subject: [PATCH 09/14] Adjust join related to code to accept child relations.
Existing join related code doesn't expect child relations to be joined. This
patch contains various fixes to change that.
1. Uniqe-ifying joining relations.
=================================
For semi-joins we unique-ify the joining relations, which tries to estimate
nummber of unique values using estimate_num_groups(). This function doesn't
expect a Var from a child relation and contained an assertion to that effect.
With partition-wise joins, we may compute a join between child relations. This
commit changes that assertion to include child relation. The function doesn't
need any change other than that to accomodate child relations.
2. OUTER joins require dummy child relations to have targetlist.
================================================================
We need a targetlist defining nullable columns for an outer join, even if the
relation on the nullable side is deemed to be empty. Prior to partition-wise
join an empty child relation never had a targetlist since it was eliminated
from planning. But with partition-wise join an empty child relation may
participate in an outer join with another non-empty child relation. Hence set
targetlist for a child relation even if it's dummy.
3. prepare_sort_from_pathkeys fixes.
====================================
Before partition-wise join feature were never required to be directly sorted,
let's say for merge joins. With partition-wise join feature, the child
relations will participate directly in the join and also need to be sorted
directly for the purpose of merge join. In order to sort a relation, we use
pathkeys. The expression on which to sort a particular relation is provided by
the equivalence member corresponding to that relation in the equivalence class
referred by the pathkeys. Since the code doesn't expect child relations to
bubble up to the sorting, the function prepare_sort_from_pathkeys() skips any
child members (those set with em_is_child) unless the caller specifically asks
for child relations by passing relids. make_sort_from_pathkeys() calls
prepare_sort_from_pathkeys() to create Sort plan for outer and inner plans
without passing relids of the relation to be sorted. For partition-wise joins
the outer and inner plans produce child relations and thus
prepare_sort_from_pathkeys() does not find equivalence members since it skips
child members for the want of relids. This particular instance can be fixed by
passing outer/inner_path->parent->relids to prepare_sort_from_pathkeys().
All the callers of prepare_sort_from_pathkeys() viz.
create_merge_append_plan(), create_merge_append_plan(),
create_windowagg_plan() except make_sort_from_pathkeys() pass relids to
prepare_sort_from_pathkeys(). make_sort_from_pathkeys() as well passes those
with this patch.
make_sort_from_pathkeys() itself doesn't know the relids of relation being
sorted. It just gets the plan. Hence we need to pass relids to
make_sort_from_pathkeys() and thus change each of its callers to pass relids,
if required.
It has two callers as of now.
1. create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags): does
not handle child relations yet, so doesn't need any change.
2. create_mergejoin_plan(PlannerInfo *root, MergePath *best_path):
It requires this change and the relids can be obtained from the outer and inner
path's parent RelOptInfo.
4. Handling em_is_child cases.
==============================
Right now, when comparing relids for child relations, only exact match is
considered. This is fine as long as em_relids has only a single member in it
and the passed in relids has only a single member in it. But with
partition-wise join, relids can have multiple members and em_relids may not
exactly match the given relids. But we need to find the member which covers
subset of given relids.
---
src/backend/optimizer/path/allpaths.c | 41 +++++++++++++++++--------------
src/backend/optimizer/plan/createplan.c | 28 +++++++++++++--------
src/backend/utils/adt/selfuncs.c | 3 ++-
3 files changed, 42 insertions(+), 30 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index cebf359..0401269 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -957,11 +957,27 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
}
/*
- * We have to copy the parent's targetlist and quals to the child,
- * with appropriate substitution of variables. However, only the
- * baserestrictinfo quals are needed before we can check for
- * constraint exclusion; so do that first and then check to see if we
- * can disregard this child.
+ * Copy/Modify targetlist. Even if this child is deemed empty, we need
+ * its targetlist in case it falls on nullable side in a child-join
+ * because of partition-wise join.
+ *
+ * NB: the resulting childrel->reltarget->exprs may contain arbitrary
+ * expressions, which otherwise would not occur in a rel's targetlist.
+ * Code that might be looking at an appendrel child must cope with
+ * such. (Normally, a rel's targetlist would only include Vars and
+ * PlaceHolderVars.) XXX we do not bother to update the cost or width
+ * fields of childrel->reltarget; not clear if that would be useful.
+ */
+ childrel->reltarget->exprs = (List *)
+ adjust_appendrel_attrs(root,
+ (Node *) rel->reltarget->exprs,
+ appinfo_list);
+
+ /*
+ * We have to copy the parent's quals to the child, with appropriate
+ * substitution of variables. However, only the baserestrictinfo quals
+ * are needed before we can check for constraint exclusion; so do that
+ * first and then check to see if we can disregard this child.
*
* The child rel's targetlist might contain non-Var expressions, which
* means that substitution into the quals could produce opportunities
@@ -1088,22 +1104,9 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
continue;
}
- /*
- * CE failed, so finish copying/modifying targetlist and join quals.
- *
- * NB: the resulting childrel->reltarget->exprs may contain arbitrary
- * expressions, which otherwise would not occur in a rel's targetlist.
- * Code that might be looking at an appendrel child must cope with
- * such. (Normally, a rel's targetlist would only include Vars and
- * PlaceHolderVars.) XXX we do not bother to update the cost or width
- * fields of childrel->reltarget; not clear if that would be useful.
- */
+ /* CE failed, so finish copying/modifying targetlist and join quals. */
childrel->joininfo = build_child_clauses(root, rel->joininfo,
appinfo_list);
- childrel->reltarget->exprs = (List *)
- adjust_appendrel_attrs(root,
- (Node *) rel->reltarget->exprs,
- appinfo_list);
/*
* We have to make child entries in the EquivalenceClass data
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index c1f9da2..3f1f2c1 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -245,7 +245,8 @@ static Plan *prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
static EquivalenceMember *find_ec_member_for_tle(EquivalenceClass *ec,
TargetEntry *tle,
Relids relids);
-static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys);
+static Sort *make_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
+ Relids relids);
static Sort *make_sort_from_groupcols(List *groupcls,
AttrNumber *grpColIdx,
Plan *lefttree);
@@ -1555,7 +1556,7 @@ create_sort_plan(PlannerInfo *root, SortPath *best_path, int flags)
subplan = create_plan_recurse(root, best_path->subpath,
flags | CP_SMALL_TLIST);
- plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys);
+ plan = make_sort_from_pathkeys(subplan, best_path->path.pathkeys, NULL);
copy_generic_path_info(&plan->plan, (Path *) best_path);
@@ -3572,6 +3573,8 @@ create_mergejoin_plan(PlannerInfo *root,
ListCell *lc;
ListCell *lop;
ListCell *lip;
+ Path *outer_path = best_path->jpath.outerjoinpath;
+ Path *inner_path = best_path->jpath.innerjoinpath;
/*
* MergeJoin can project, so we don't have to demand exact tlists from the
@@ -3635,8 +3638,10 @@ create_mergejoin_plan(PlannerInfo *root,
*/
if (best_path->outersortkeys)
{
+ Relids outer_relids = outer_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(outer_plan,
- best_path->outersortkeys);
+ best_path->outersortkeys,
+ outer_relids);
label_sort_with_costsize(root, sort, -1.0);
outer_plan = (Plan *) sort;
@@ -3647,8 +3652,10 @@ create_mergejoin_plan(PlannerInfo *root,
if (best_path->innersortkeys)
{
+ Relids inner_relids = inner_path->parent->relids;
Sort *sort = make_sort_from_pathkeys(inner_plan,
- best_path->innersortkeys);
+ best_path->innersortkeys,
+ inner_relids);
label_sort_with_costsize(root, sort, -1.0);
inner_plan = (Plan *) sort;
@@ -5631,11 +5638,11 @@ prepare_sort_from_pathkeys(Plan *lefttree, List *pathkeys,
continue;
/*
- * Ignore child members unless they match the rel being
+ * Ignore child members unless they belong to the rel being
* sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
sortexpr = em->em_expr;
@@ -5746,10 +5753,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
continue;
/*
- * Ignore child members unless they match the rel being sorted.
+ * Ignore child members unless they belong to the rel being sorted.
*/
if (em->em_is_child &&
- !bms_equal(em->em_relids, relids))
+ !bms_is_subset(em->em_relids, relids))
continue;
/* Match if same expression (after stripping relabel) */
@@ -5770,9 +5777,10 @@ find_ec_member_for_tle(EquivalenceClass *ec,
*
* 'lefttree' is the node which yields input tuples
* 'pathkeys' is the list of pathkeys by which the result is to be sorted
+ * 'relids' is the set of relations required by prepare_sort_from_pathkeys()
*/
static Sort *
-make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
+make_sort_from_pathkeys(Plan *lefttree, List *pathkeys, Relids relids)
{
int numsortkeys;
AttrNumber *sortColIdx;
@@ -5782,7 +5790,7 @@ make_sort_from_pathkeys(Plan *lefttree, List *pathkeys)
/* Compute sort column info, and adjust lefttree as needed */
lefttree = prepare_sort_from_pathkeys(lefttree, pathkeys,
- NULL,
+ relids,
NULL,
false,
&numsortkeys,
diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c
index fa32e9e..c833846 100644
--- a/src/backend/utils/adt/selfuncs.c
+++ b/src/backend/utils/adt/selfuncs.c
@@ -3427,7 +3427,8 @@ estimate_num_groups(PlannerInfo *root, List *groupExprs, double input_rows,
/*
* Sanity check --- don't divide by zero if empty relation.
*/
- Assert(rel->reloptkind == RELOPT_BASEREL);
+ Assert(rel->reloptkind == RELOPT_BASEREL ||
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
if (rel->tuples > 0)
{
/*
--
1.7.9.5
0010-Parameterized-path-fixes.patchapplication/octet-stream; name=0010-Parameterized-path-fixes.patchDownload
From 633152ec443469a5a6611f7005db2b52474a60f7 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Tue, 7 Feb 2017 17:25:25 +0530
Subject: [PATCH 10/14] Parameterized path fixes.
We do not create merge or hash join paths when the inner path is parameterized
by the outer and vice-versa. Parameterization information in path refers to the
top-most parent relation. Current tests (PATH_PARAM_BY_REL) to avoid joining
such paths fail while joining child relations; the paths from either child may
be paramterized by other's parent. Modify the tests to consider paths
parameterized by parent as parameterized by any of its child.
If the inner path is parameterized by outer path, we can create a nested loop
join using those two paths with inner relation parameterized by the outer
relation. For LATERAL JOINs this is the only legal way to plan a join. In case
of partitioned joins, the lateral references refer to the topmost parent and
hence inner paths are parameterized by the topmost parent. In such cases, it's
possible to translate the inner path to be parameterized by
the child and create nested loop join. When presented with a pair of child
relation paths, where the inner paths is parameterized by the parent of outer
child, this patch translates the path to be parameterized by the outer child
and creates a nested loop join path.
The function reparameterize_path_by_child() needs to call adjust_relid_set() to
substitute parent relids by child relids in Path::param_info::ppi_req_outer.
Hence "extern"alized that function. Since there is already another
static adjust_relid_set() in rewriteManip.c, renamed this one to
adjust_child_relids().
Also "extern"alized find_param_path_info() required by
reparameterize_path_by_child().
---
src/backend/optimizer/path/joinpath.c | 33 +++++-
src/backend/optimizer/prep/prepunion.c | 42 ++++----
src/backend/optimizer/util/pathnode.c | 182 ++++++++++++++++++++++++++++++++
src/backend/optimizer/util/relnode.c | 2 -
src/include/optimizer/pathnode.h | 4 +
src/include/optimizer/prep.h | 1 +
6 files changed, 239 insertions(+), 25 deletions(-)
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index f80fb25..4d4a183 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -25,9 +25,19 @@
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
-#define PATH_PARAM_BY_REL(path, rel) \
+/*
+ * Paths parameterized by the parent can be considered to be parameterized by
+ * any of its child.
+ */
+#define PATH_PARAM_BY_PARENT(path, rel) \
+ ((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), \
+ (rel)->top_parent_relids))
+#define PATH_PARAM_BY_REL_SELF(path, rel) \
((path)->param_info && bms_overlap(PATH_REQ_OUTER(path), (rel)->relids))
+#define PATH_PARAM_BY_REL(path, rel) \
+ (PATH_PARAM_BY_REL_SELF(path, rel) || PATH_PARAM_BY_PARENT(path, rel))
+
static void sort_inner_and_outer(PlannerInfo *root, RelOptInfo *joinrel,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, JoinPathExtraData *extra);
@@ -301,6 +311,27 @@ try_nestloop_path(PlannerInfo *root,
JoinCostWorkspace workspace;
/*
+ * Since result produced by a child is part of the result produced by its
+ * topmost parent and has same properties, the parameters representing that
+ * parent may be substituted by values from a child. Hence expressions and
+ * hence paths using those expressions, parameterized by a parent can be
+ * said to be parameterized by any of its child. For a join between child
+ * relations, if the inner path is parameterized by the parent of the outer
+ * relation, create a nestloop join path with inner relation parameterized
+ * by the outer relation by translating the inner path to be parameterized
+ * by the outer child relation.
+ */
+ if (PATH_PARAM_BY_PARENT(inner_path, outer_path->parent))
+ {
+ inner_path = reparameterize_path_by_child(root, inner_path,
+ outer_path->parent);
+
+ /* If we could not translate the path, don't produce nest loop path. */
+ if (!inner_path)
+ return;
+ }
+
+ /*
* Check to see if proposed path is still parameterized, and reject if the
* parameterization wouldn't be sensible --- unless allow_star_schema_join
* says to allow it anyway. Also, we must reject if have_dangerous_phv
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 676204f..d459e95 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -109,7 +109,6 @@ static Node *adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_context *context);
static List *adjust_inherited_tlist(List *tlist,
AppendRelInfo *context);
-static Relids adjust_relid_set(Relids relids, List *append_rel_infos);
/*
@@ -1951,7 +1950,7 @@ adjust_appendrel_attrs_mutator(Node *node,
(void *) context);
/* now fix PlaceHolderVar's relid sets */
if (phv->phlevelsup == 0)
- phv->phrels = adjust_relid_set(phv->phrels, context->appinfos);
+ phv->phrels = adjust_child_relids(phv->phrels, context->appinfos);
return (Node *) phv;
}
/* Shouldn't need to handle planner auxiliary nodes here */
@@ -1982,17 +1981,17 @@ adjust_appendrel_attrs_mutator(Node *node,
adjust_appendrel_attrs_mutator((Node *) oldinfo->orclause, context);
/* adjust relid sets too */
- newinfo->clause_relids = adjust_relid_set(oldinfo->clause_relids,
+ newinfo->clause_relids = adjust_child_relids(oldinfo->clause_relids,
context->appinfos);
- newinfo->required_relids = adjust_relid_set(oldinfo->required_relids,
+ newinfo->required_relids = adjust_child_relids(oldinfo->required_relids,
context->appinfos);
- newinfo->outer_relids = adjust_relid_set(oldinfo->outer_relids,
+ newinfo->outer_relids = adjust_child_relids(oldinfo->outer_relids,
context->appinfos);
- newinfo->nullable_relids = adjust_relid_set(oldinfo->nullable_relids,
+ newinfo->nullable_relids = adjust_child_relids(oldinfo->nullable_relids,
context->appinfos);
- newinfo->left_relids = adjust_relid_set(oldinfo->left_relids,
+ newinfo->left_relids = adjust_child_relids(oldinfo->left_relids,
context->appinfos);
- newinfo->right_relids = adjust_relid_set(oldinfo->right_relids,
+ newinfo->right_relids = adjust_child_relids(oldinfo->right_relids,
context->appinfos);
/*
@@ -2026,15 +2025,18 @@ adjust_appendrel_attrs_mutator(Node *node,
/*
* Replace parent relids by child relids in the copy of given relid set
- * according to the given list of AppendRelInfos. The given relid set is
- * returned as is if it contains no parent in the given list, otherwise, the
- * given relid set is not changed.
+ * according to the given list of AppendRelInfos.
*/
Relids
-adjust_relid_set(Relids relids, List *append_rel_infos)
+adjust_child_relids(Relids relids, List *append_rel_infos)
{
ListCell *lc;
- Bitmapset *result = NULL;
+
+ /*
+ * The new relids set may be expected to be in a memory context different
+ * from the given one. Make a copy here.
+ */
+ Bitmapset *result = bms_copy(relids);
foreach (lc, append_rel_infos)
{
@@ -2043,10 +2045,6 @@ adjust_relid_set(Relids relids, List *append_rel_infos)
/* Remove parent, add child */
if (bms_is_member(appinfo->parent_relid, relids))
{
- /* Make a copy if we are changing the set. */
- if (!result)
- result = bms_copy(relids);
-
result = bms_del_member(result, appinfo->parent_relid);
result = bms_add_member(result, appinfo->child_relid);
}
@@ -2202,7 +2200,7 @@ build_child_restrictinfo(PlannerInfo *root, RestrictInfo *rinfo,
RestrictInfo *child_rinfo;
MemoryContext old_context;
- child_required_relids = adjust_relid_set(rinfo->required_relids,
+ child_required_relids = adjust_child_relids(rinfo->required_relids,
append_rel_infos);
@@ -2313,13 +2311,13 @@ build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo,
memcpy(sjinfo, parent_sjinfo, sizeof(SpecialJoinInfo));
- sjinfo->min_lefthand = adjust_relid_set(sjinfo->min_lefthand,
+ sjinfo->min_lefthand = adjust_child_relids(sjinfo->min_lefthand,
left_appinfos);
- sjinfo->min_righthand = adjust_relid_set(sjinfo->min_righthand,
+ sjinfo->min_righthand = adjust_child_relids(sjinfo->min_righthand,
right_appinfos);
- sjinfo->syn_lefthand = adjust_relid_set(sjinfo->syn_lefthand,
+ sjinfo->syn_lefthand = adjust_child_relids(sjinfo->syn_lefthand,
left_appinfos);
- sjinfo->syn_righthand = adjust_relid_set(sjinfo->syn_righthand,
+ sjinfo->syn_righthand = adjust_child_relids(sjinfo->syn_righthand,
right_appinfos);
/*
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index d861a49..d1ee237 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -3388,3 +3388,185 @@ reparameterize_path(PlannerInfo *root, Path *path,
}
return NULL;
}
+
+/*
+ * reparameterize_path_by_child
+ * Given a path parameterized by the parent of the given relation,
+ * translate the path to be parameterized by the given child relation.
+ *
+ * The function creates a new path of the same type as the given path, but
+ * parameterized by the given child relation. If it can not reparameterize the
+ * path as required, it returns NULL.
+ *
+ * The cost, number of rows, width and parallel path properties depend upon
+ * path->parent, which does not change during the translation. Hence those
+ * members are copied as they are.
+ */
+
+Path *
+reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel)
+{
+ Path *new_path;
+ ParamPathInfo *new_ppi;
+ ParamPathInfo *old_ppi;
+ List *child_aris;
+ Relids required_outer;
+
+ /*
+ * If the path is not parameterized by parent of the given relation or it it
+ * doesn't need reparameterization.
+ */
+ if (!path->param_info ||
+ !bms_overlap(PATH_REQ_OUTER(path), child_rel->top_parent_relids))
+ return path;
+
+ switch (nodeTag(path))
+ {
+ case T_Path:
+ new_path = makeNode(Path);
+ memcpy(new_path, path, sizeof(Path));
+ break;
+
+ case T_HashPath:
+ new_path = (Path *) makeNode(HashPath);
+ memcpy(new_path, path, sizeof(HashPath));
+ break;
+
+ case T_MergePath:
+ new_path = (Path *) makeNode(MergePath);
+ memcpy(new_path, path, sizeof(MergePath));
+ break;
+
+ case T_NestPath:
+ new_path = (Path *) makeNode(NestPath);
+ memcpy(new_path, path, sizeof(NestPath));
+ break;
+
+ case T_IndexPath:
+ new_path = (Path *) makeNode(IndexPath);
+ memcpy(new_path, path, sizeof(IndexPath));
+ break;
+
+ case T_AppendPath:
+ new_path = (Path *) makeNode(AppendPath);
+ memcpy(new_path, path, sizeof(AppendPath));
+ break;
+
+ /*
+ * TODO:
+ * If this method of translation is fine add more path types here.
+ */
+
+ default:
+ /* Path type unsupported by this function. */
+ return NULL;
+ }
+
+ /*
+ * Gather AppendRelInfos of the base partition relations in the outer child
+ * relation. We need those for translating parent path to that of child by
+ * substituting parent Var nodes and relids with those of children.
+ */
+ child_aris = find_appinfos_by_relids(root, child_rel->relids);
+
+ /* Adjust the parameterization information. */
+ old_ppi = new_path->param_info;
+ required_outer = adjust_child_relids(old_ppi->ppi_req_outer, child_aris);
+
+ /* If we already have a PPI for this parameterization, just return it */
+ new_ppi = find_param_path_info(new_path->parent, required_outer);
+
+ /* If not build a new one and link it to the list of PPIs. */
+ if (!new_ppi)
+ {
+ new_ppi = makeNode(ParamPathInfo);
+ new_ppi->ppi_req_outer = required_outer;
+ new_ppi->ppi_rows = old_ppi->ppi_rows;
+ new_ppi->ppi_clauses = build_child_clauses(root, old_ppi->ppi_clauses,
+ child_aris);
+ new_path->parent->ppilist = lappend(new_path->parent->ppilist, new_ppi);
+ }
+ else
+ bms_free(required_outer);
+
+ new_path->param_info = new_ppi;
+
+ /*
+ * Adjust the path target if the parent of the outer relation is referenced
+ * in the targetlist. This can happen when only the parent of outer relation is
+ * laterally referenced in this relation.
+ */
+ if (bms_overlap(path->parent->lateral_relids, child_rel->top_parent_relids))
+ {
+ MemoryContext old_context;
+
+ /*
+ * Allocate the target in planner's context, since they are copied as
+ * is from path while creating plans.
+ */
+ old_context = MemoryContextSwitchTo(root->planner_cxt);
+ new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
+ new_path->pathtarget->exprs = (List *) adjust_appendrel_attrs(root,
+ (Node *) new_path->pathtarget->exprs,
+ child_aris);
+ MemoryContextSwitchTo(old_context);
+ }
+
+ /*
+ * Change parameterization of subpaths recursively. Also carry out any
+ * pathtype specific adjustments.
+ */
+ switch (nodeTag(path))
+ {
+ case T_HashPath:
+ case T_MergePath:
+ case T_NestPath:
+ {
+ JoinPath *jpath = (JoinPath *)new_path;
+
+ jpath->outerjoinpath = reparameterize_path_by_child(root,
+ jpath->outerjoinpath,
+ child_rel);
+ jpath->innerjoinpath = reparameterize_path_by_child(root,
+ jpath->innerjoinpath,
+ child_rel);
+ jpath->joinrestrictinfo = build_child_clauses(root,
+ jpath->joinrestrictinfo,
+ child_aris);
+ }
+ break;
+
+ case T_AppendPath:
+ {
+ AppendPath *apath = (AppendPath *)new_path;
+ List *subpaths = NIL;
+ ListCell *lc;
+
+ foreach (lc, apath->subpaths)
+ subpaths = lappend(subpaths,
+ reparameterize_path_by_child(root,
+ lfirst(lc),
+ child_rel));
+ apath->subpaths = subpaths;
+ }
+ break;
+
+ case T_IndexPath:
+ {
+ IndexPath *ipath = (IndexPath *)new_path;
+
+ ipath->indexclauses = build_child_clauses(root, ipath->indexclauses,
+ child_aris);
+ ipath->indexquals = build_child_clauses(root, ipath->indexquals,
+ child_aris);
+ }
+ break;
+
+ default:
+ /* Nothing to do. */
+ break;
+ }
+
+ return new_path;
+}
diff --git a/src/backend/optimizer/util/relnode.c b/src/backend/optimizer/util/relnode.c
index 1eed987..46eea02 100644
--- a/src/backend/optimizer/util/relnode.c
+++ b/src/backend/optimizer/util/relnode.c
@@ -53,8 +53,6 @@ static List *subbuild_joinrel_joinlist(RelOptInfo *joinrel,
static void set_foreign_rel_properties(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel);
static void add_join_rel(PlannerInfo *root, RelOptInfo *joinrel);
-extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
- Relids required_outer);
static void build_joinrel_partition_info(RelOptInfo *joinrel,
RelOptInfo *outer_rel, RelOptInfo *inner_rel,
JoinType jointype);
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 81d637a..b9f5b11 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -236,6 +236,8 @@ extern PartitionJoinPath *create_partition_join_path(PlannerInfo *root,
extern Path *reparameterize_path(PlannerInfo *root, Path *path,
Relids required_outer,
double loop_count);
+extern Path *reparameterize_path_by_child(PlannerInfo *root, Path *path,
+ RelOptInfo *child_rel);
/*
* prototypes for relnode.c
@@ -277,5 +279,7 @@ extern ParamPathInfo *get_appendrel_parampathinfo(RelOptInfo *appendrel,
extern RelOptInfo *build_child_join_rel(PlannerInfo *root,
RelOptInfo *outer_rel, RelOptInfo *inner_rel,
RelOptInfo *parent_joinrel, JoinType jointype);
+extern ParamPathInfo *find_param_path_info(RelOptInfo *rel,
+ Relids required_outer);
#endif /* PATHNODE_H */
diff --git a/src/include/optimizer/prep.h b/src/include/optimizer/prep.h
index 5832130..0347b37 100644
--- a/src/include/optimizer/prep.h
+++ b/src/include/optimizer/prep.h
@@ -65,5 +65,6 @@ extern List *find_appinfos_by_relids(PlannerInfo *root, Relids relids);
extern SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root,
SpecialJoinInfo *parent_sjinfo,
Relids left_relids, Relids right_relids);
+extern Relids adjust_child_relids(Relids relids, List *append_rel_infos);
#endif /* PREP_H */
--
1.7.9.5
0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patchapplication/octet-stream; name=0011-Use-IS_JOIN_REL-instead-of-RELOPT_JOINREL.patchDownload
From bdcf020d6b0708901949476d5ce59622979d566c Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 8 Feb 2017 14:42:15 +0530
Subject: [PATCH 11/14] Use IS_JOIN_REL() instead of RELOPT_JOINREL
FDW code uses RELOPT_JOINREL to check whether a given relation is a join or
not. Partition-wise joins create child-join relations, which are marked as
RELOPT_OTHER_JOINREL. Macro IS_JOIN_REL() returns true for both of those kinds,
replace RELOPT_JOINREL tests with IS_JOIN_REL() test.
Similarly replace RELOPT_OTHER_MEMBER_REL test with IS_OTHER_REL() where we
want to test for child relations of all kinds.
---
contrib/postgres_fdw/deparse.c | 10 +++++-----
contrib/postgres_fdw/postgres_fdw.c | 10 ++++++----
src/backend/foreign/foreign.c | 6 +++---
3 files changed, 14 insertions(+), 12 deletions(-)
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index d2b94aa..a2171d7 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -911,7 +911,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
* We handle relations for foreign tables, joins between those and upper
* relations.
*/
- Assert(rel->reloptkind == RELOPT_JOINREL ||
+ Assert(IS_JOIN_REL(rel) ||
rel->reloptkind == RELOPT_BASEREL ||
rel->reloptkind == RELOPT_OTHER_MEMBER_REL ||
rel->reloptkind == RELOPT_UPPER_REL);
@@ -990,7 +990,7 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
@@ -1030,7 +1030,7 @@ deparseFromExpr(List *quals, deparse_expr_cxt *context)
/* For upper relations, scanrel must be either a joinrel or a baserel */
Assert(context->foreignrel->reloptkind != RELOPT_UPPER_REL ||
- scanrel->reloptkind == RELOPT_JOINREL ||
+ IS_JOIN_REL(scanrel) ||
scanrel->reloptkind == RELOPT_BASEREL);
/* Construct FROM clause */
@@ -1178,7 +1178,7 @@ deparseLockingClause(deparse_expr_cxt *context)
appendStringInfoString(buf, " FOR UPDATE");
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(rel))
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
else
@@ -1342,7 +1342,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
{
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreignrel))
{
RelOptInfo *rel_o = fpinfo->outerrel;
RelOptInfo *rel_i = fpinfo->innerrel;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index 5d270b9..2487f26 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -723,6 +723,8 @@ get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel)
/* If this is a child rel, we must use the topmost parent rel to search. */
if (rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
relids = find_childrel_top_parent(root, rel)->relids;
+ else if (rel->reloptkind == RELOPT_OTHER_JOINREL)
+ relids = rel->top_parent_relids;
else
relids = rel->relids;
@@ -1181,7 +1183,7 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
@@ -1247,7 +1249,7 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2527,7 +2529,7 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ if (IS_JOIN_REL(foreignrel) ||
foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
@@ -2609,7 +2611,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind == RELOPT_JOINREL)
+ else if (IS_JOIN_REL(foreignrel))
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index fdb4f71..e8ca7df 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -717,7 +717,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
{
ListCell *lc;
- Assert(joinrel->reloptkind == RELOPT_JOINREL);
+ Assert(IS_JOIN_REL(joinrel));
foreach(lc, joinrel->pathlist)
{
@@ -782,7 +782,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->outerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->outerjoinpath = foreign_path->fdw_outerpath;
}
@@ -791,7 +791,7 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
ForeignPath *foreign_path;
foreign_path = (ForeignPath *) joinpath->innerjoinpath;
- if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL)
+ if (IS_JOIN_REL(foreign_path->path.parent))
joinpath->innerjoinpath = foreign_path->fdw_outerpath;
}
--
1.7.9.5
0012-Multi-level-partitioned-table-expansion.patchapplication/octet-stream; name=0012-Multi-level-partitioned-table-expansion.patchDownload
From 389e0adf55085470f3fdbbfad8521f758cc45136 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 10 Feb 2017 13:50:14 +0530
Subject: [PATCH 12/14] Multi-level partitioned table expansion.
Construct inheritance hierarchy of a partitioned table to reflect the partition
hierarchy. Propagate lateral join information down the partition hierarchy.
---
src/backend/optimizer/plan/initsplan.c | 14 +++++-
src/backend/optimizer/prep/prepunion.c | 78 +++++++++++++++++++++-----------
src/test/regress/expected/inherit.out | 38 ++++++++--------
3 files changed, 83 insertions(+), 47 deletions(-)
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index c170e96..e302f4f 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -628,7 +628,19 @@ create_lateral_join_info(PlannerInfo *root)
{
RelOptInfo *brel = root->simple_rel_array[rti];
- if (brel == NULL || brel->reloptkind != RELOPT_BASEREL)
+ if (brel == NULL)
+ continue;
+
+ /*
+ * If an "other rel" RTE is a "partitioned table", we must propagate
+ * the lateral info inherited all the way from the root parent to its
+ * children. That's because the children are not linked directly with
+ * the root parent via AppendRelInfo's unlike in case of a regular
+ * inheritance set (see expand_inherited_rtentry()). Failing to
+ * do this would result in those children not getting marked with the
+ * appropriate lateral info.
+ */
+ if (brel->reloptkind != RELOPT_BASEREL && !brel->part_scheme)
continue;
if (root->simple_rte_array[rti]->inh)
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index d459e95..63b45d6 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -98,7 +98,7 @@ static List *generate_append_tlist(List *colTypes, List *colCollations,
List *refnames_tlist);
static List *generate_setop_grouplist(SetOperationStmt *op, List *targetlist);
static void expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte,
- Index rti);
+ Index rti, LOCKMODE lockmode);
static void make_inh_translation_list(Relation oldrelation,
Relation newrelation,
Index newvarno,
@@ -1319,19 +1319,44 @@ expand_inherited_tables(PlannerInfo *root)
Index nrtes;
Index rti;
ListCell *rl;
+ Query *parse = root->parse;
/*
* expand_inherited_rtentry may add RTEs to parse->rtable; there is no
* need to scan them since they can't have inh=true. So just scan as far
* as the original end of the rtable list.
*/
- nrtes = list_length(root->parse->rtable);
- rl = list_head(root->parse->rtable);
+ nrtes = list_length(parse->rtable);
+ rl = list_head(parse->rtable);
for (rti = 1; rti <= nrtes; rti++)
{
RangeTblEntry *rte = (RangeTblEntry *) lfirst(rl);
+ LOCKMODE lockmode;
+ PlanRowMark *oldrc;
- expand_inherited_rtentry(root, rte, rti);
+ /*
+ * The rewriter should already have obtained an appropriate lock on
+ * each relation named in the query. However, for each child relation
+ * we add to the query, we must obtain an appropriate lock, because
+ * this will be the first use of those relations in the
+ * parse/rewrite/plan pipeline.
+ *
+ * If the parent relation is the query's result relation, then we need
+ * RowExclusiveLock. Otherwise, if it's accessed FOR UPDATE/SHARE, we
+ * need RowShareLock; otherwise AccessShareLock. We can't just grab
+ * AccessShareLock because then the executor would be trying to upgrade
+ * the lock, leading to possible deadlocks. (This code should match
+ * the parser and rewriter.)
+ */
+ oldrc = get_plan_rowmark(root->rowMarks, rti);
+ if (rti == parse->resultRelation)
+ lockmode = RowExclusiveLock;
+ else if (oldrc && RowMarkRequiresRowShareLock(oldrc->markType))
+ lockmode = RowShareLock;
+ else
+ lockmode = AccessShareLock;
+
+ expand_inherited_rtentry(root, rte, rti, lockmode);
rl = lnext(rl);
}
}
@@ -1353,13 +1378,13 @@ expand_inherited_tables(PlannerInfo *root)
* a parent RTE must always have at least two associated AppendRelInfos.
*/
static void
-expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
+expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti,
+ LOCKMODE lockmode)
{
Query *parse = root->parse;
Oid parentOID;
PlanRowMark *oldrc;
Relation oldrelation;
- LOCKMODE lockmode;
List *inhOIDs;
List *appinfos;
ListCell *l;
@@ -1383,28 +1408,18 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
}
/*
- * The rewriter should already have obtained an appropriate lock on each
- * relation named in the query. However, for each child relation we add
- * to the query, we must obtain an appropriate lock, because this will be
- * the first use of those relations in the parse/rewrite/plan pipeline.
- *
- * If the parent relation is the query's result relation, then we need
- * RowExclusiveLock. Otherwise, if it's accessed FOR UPDATE/SHARE, we
- * need RowShareLock; otherwise AccessShareLock. We can't just grab
- * AccessShareLock because then the executor would be trying to upgrade
- * the lock, leading to possible deadlocks. (This code should match the
- * parser and rewriter.)
+ * Expand partitioned table level-wise to help optimizations like
+ * partition-wise join which match partitions at every level. Otherwise,
+ * scan for all members of inheritance set. Acquire needed locks
*/
- oldrc = get_plan_rowmark(root->rowMarks, rti);
- if (rti == parse->resultRelation)
- lockmode = RowExclusiveLock;
- else if (oldrc && RowMarkRequiresRowShareLock(oldrc->markType))
- lockmode = RowShareLock;
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ {
+ inhOIDs = list_make1_oid(parentOID);
+ inhOIDs = list_concat(inhOIDs,
+ find_inheritance_children(parentOID, lockmode));
+ }
else
- lockmode = AccessShareLock;
-
- /* Scan for all members of inheritance set, acquire needed locks */
- inhOIDs = find_all_inheritors(parentOID, lockmode, NULL);
+ inhOIDs = find_all_inheritors(parentOID, lockmode, NULL);
/*
* Check that there's at least one descendant, else treat as no-child
@@ -1418,6 +1433,7 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
return;
}
+ oldrc = get_plan_rowmark(root->rowMarks, rti);
/*
* If parent relation is selected FOR UPDATE/SHARE, we need to mark its
* PlanRowMark as isParent = true, and generate a new PlanRowMark for each
@@ -1475,7 +1491,12 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
childrte = copyObject(rte);
childrte->relid = childOID;
childrte->relkind = newrelation->rd_rel->relkind;
- childrte->inh = false;
+ /* A partitioned child will need to be expanded further. */
+ if (childOID != parentOID &&
+ childrte->relkind == RELKIND_PARTITIONED_TABLE)
+ childrte->inh = true;
+ else
+ childrte->inh = false;
childrte->requiredPerms = 0;
childrte->securityQuals = NIL;
parse->rtable = lappend(parse->rtable, childrte);
@@ -1539,6 +1560,9 @@ expand_inherited_rtentry(PlannerInfo *root, RangeTblEntry *rte, Index rti)
/* Close child relations, but keep locks */
if (childOID != parentOID)
heap_close(newrelation, NoLock);
+
+ /* Expand partitioned children recursively. */
+ expand_inherited_rtentry(root, childrte, childRTindex, lockmode);
}
heap_close(oldrelation, NoLock);
diff --git a/src/test/regress/expected/inherit.out b/src/test/regress/expected/inherit.out
index a8c8b28..6941045 100644
--- a/src/test/regress/expected/inherit.out
+++ b/src/test/regress/expected/inherit.out
@@ -1694,15 +1694,15 @@ explain (costs off) select * from range_list_parted;
Append
-> Seq Scan on range_list_parted
-> Seq Scan on part_1_10
- -> Seq Scan on part_10_20
- -> Seq Scan on part_21_30
- -> Seq Scan on part_40_inf
-> Seq Scan on part_1_10_ab
-> Seq Scan on part_1_10_cd
+ -> Seq Scan on part_10_20
-> Seq Scan on part_10_20_ab
-> Seq Scan on part_10_20_cd
+ -> Seq Scan on part_21_30
-> Seq Scan on part_21_30_ab
-> Seq Scan on part_21_30_cd
+ -> Seq Scan on part_40_inf
-> Seq Scan on part_40_inf_ab
-> Seq Scan on part_40_inf_cd
-> Seq Scan on part_40_inf_null
@@ -1730,18 +1730,18 @@ explain (costs off) select * from range_list_parted where b = 'ab';
Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_1_10
Filter: (b = 'ab'::bpchar)
- -> Seq Scan on part_10_20
- Filter: (b = 'ab'::bpchar)
- -> Seq Scan on part_21_30
- Filter: (b = 'ab'::bpchar)
- -> Seq Scan on part_40_inf
- Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_1_10_ab
Filter: (b = 'ab'::bpchar)
+ -> Seq Scan on part_10_20
+ Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_10_20_ab
Filter: (b = 'ab'::bpchar)
+ -> Seq Scan on part_21_30
+ Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_21_30_ab
Filter: (b = 'ab'::bpchar)
+ -> Seq Scan on part_40_inf
+ Filter: (b = 'ab'::bpchar)
-> Seq Scan on part_40_inf_ab
Filter: (b = 'ab'::bpchar)
(19 rows)
@@ -1754,14 +1754,14 @@ explain (costs off) select * from range_list_parted where a between 3 and 23 and
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_1_10
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
- -> Seq Scan on part_10_20
- Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
- -> Seq Scan on part_21_30
- Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_1_10_ab
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
+ -> Seq Scan on part_10_20
+ Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_10_20_ab
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
+ -> Seq Scan on part_21_30
+ Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
-> Seq Scan on part_21_30_ab
Filter: ((a >= 3) AND (a <= 23) AND (b = 'ab'::bpchar))
(15 rows)
@@ -1801,24 +1801,24 @@ explain (costs off) select * from range_list_parted where a is not null and a <
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_1_10
Filter: ((a IS NOT NULL) AND (a < 67))
- -> Seq Scan on part_10_20
- Filter: ((a IS NOT NULL) AND (a < 67))
- -> Seq Scan on part_21_30
- Filter: ((a IS NOT NULL) AND (a < 67))
- -> Seq Scan on part_40_inf
- Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_1_10_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_1_10_cd
Filter: ((a IS NOT NULL) AND (a < 67))
+ -> Seq Scan on part_10_20
+ Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_10_20_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_10_20_cd
Filter: ((a IS NOT NULL) AND (a < 67))
+ -> Seq Scan on part_21_30
+ Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_21_30_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_21_30_cd
Filter: ((a IS NOT NULL) AND (a < 67))
+ -> Seq Scan on part_40_inf
+ Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_40_inf_ab
Filter: ((a IS NOT NULL) AND (a < 67))
-> Seq Scan on part_40_inf_cd
--
1.7.9.5
0013-Multi-level-partition-wise-join-tests.patchapplication/octet-stream; name=0013-Multi-level-partition-wise-join-tests.patchDownload
From 7a458b66cea826cf4a7e4fd7a44598c902787075 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 10 Feb 2017 14:18:19 +0530
Subject: [PATCH 13/14] Multi-level partition-wise join tests.
---
.../expected/multi_level_partition_join.out | 687 ++++++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/serial_schedule | 1 +
.../regress/sql/multi_level_partition_join.sql | 95 +++
4 files changed, 784 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/multi_level_partition_join.out
create mode 100644 src/test/regress/sql/multi_level_partition_join.sql
diff --git a/src/test/regress/expected/multi_level_partition_join.out b/src/test/regress/expected/multi_level_partition_join.out
new file mode 100644
index 0000000..97b1e79
--- /dev/null
+++ b/src/test/regress/expected/multi_level_partition_join.out
@@ -0,0 +1,687 @@
+-- Encourage partition-wise join plans.
+SET partition_wise_plan_weight TO 0.1;
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (500) TO (550);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (550) TO (600);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (500) TO (525);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (525) TO (600);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a
+ -> Append
+ -> Hash Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND ((t2.c)::text = (t1.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND ((t2_1.c)::text = (t1_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND ((t2_2.c)::text = (t1_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND ((t2_3.c)::text = (t1_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c
+ -> Hash
+ Output: t1_3.a, t1_3.c
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+(56 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+(4 rows)
+
+-- left join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Append
+ -> Hash Right Join
+ Output: t1.a, t1.c, t2.b, t2.c
+ Hash Cond: ((t2.b = t1.a) AND ((t2.c)::text = (t1.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t2
+ Output: t2.b, t2.c
+ -> Hash
+ Output: t1.a, t1.c
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_1.a, t1_1.c, t2_1.b, t2_1.c
+ Hash Cond: ((t2_1.b = t1_1.a) AND ((t2_1.c)::text = (t1_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ -> Hash
+ Output: t1_1.a, t1_1.c
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_2.a, t1_2.c, t2_2.b, t2_2.c
+ Hash Cond: ((t2_2.b = t1_2.a) AND ((t2_2.c)::text = (t1_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ -> Hash
+ Output: t1_2.a, t1_2.c
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Right Join
+ Output: t1_3.a, t1_3.c, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.b = t1_3.a) AND ((t2_3.c)::text = (t1_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c
+ -> Hash
+ Output: t1_3.a, t1_3.c
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+(56 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+(12 rows)
+
+-- right join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.c, t2.b, t2.c
+ Sort Key: t1.a, t2.b
+ -> Result
+ Output: t1.a, t1.c, t2.b, t2.c
+ -> Append
+ -> Hash Right Join
+ Output: t2.b, t2.c, t1.a, t1.c
+ Hash Cond: ((t1.a = t2.b) AND ((t1.c)::text = (t2.c)::text))
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.c
+ -> Hash
+ Output: t2.b, t2.c
+ -> Seq Scan on public.prt2_l_p1 t2
+ Output: t2.b, t2.c
+ Filter: ((t2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_1.b, t2_1.c, t1_1.a, t1_1.c
+ Hash Cond: ((t1_1.a = t2_1.b) AND ((t1_1.c)::text = (t2_1.c)::text))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.c
+ -> Hash
+ Output: t2_1.b, t2_1.c
+ -> Seq Scan on public.prt2_l_p2_p1 t2_1
+ Output: t2_1.b, t2_1.c
+ Filter: ((t2_1.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_2.b, t2_2.c, t1_2.a, t1_2.c
+ Hash Cond: ((t1_2.a = t2_2.b) AND ((t1_2.c)::text = (t2_2.c)::text))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.c
+ -> Hash
+ Output: t2_2.b, t2_2.c
+ -> Seq Scan on public.prt2_l_p2_p2 t2_2
+ Output: t2_2.b, t2_2.c
+ Filter: ((t2_2.b % 25) = 0)
+ -> Hash Right Join
+ Output: t2_3.b, t2_3.c, t1_3.a, t1_3.c
+ Hash Cond: ((t1_3.a = t2_3.b) AND ((t1_3.c)::text = (t2_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.c
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.c
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.c
+ -> Hash
+ Output: t2_3.b, t2_3.c
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t2_3
+ Output: t2_3.b, t2_3.c
+ Filter: ((t2_3.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p1 t2_4
+ Output: t2_4.b, t2_4.c
+ Filter: ((t2_4.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p2 t2_5
+ Output: t2_5.b, t2_5.c
+ Filter: ((t2_5.b % 25) = 0)
+(58 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 150 | 0150 | 150 | 0150
+ 300 | 0300 | 300 | 0300
+ 450 | 0450 | 450 | 0450
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(8 rows)
+
+-- full join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: prt1_l_p1.a, prt1_l_p1.c, prt2_l_p1.b, prt2_l_p1.c
+ Sort Key: prt1_l_p1.a, prt2_l_p1.b
+ -> Append
+ -> Hash Full Join
+ Output: prt1_l_p1.a, prt1_l_p1.c, prt2_l_p1.b, prt2_l_p1.c
+ Hash Cond: ((prt1_l_p1.a = prt2_l_p1.b) AND ((prt1_l_p1.c)::text = (prt2_l_p1.c)::text))
+ -> Seq Scan on public.prt1_l_p1
+ Output: prt1_l_p1.a, prt1_l_p1.c
+ Filter: ((prt1_l_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p1.b, prt2_l_p1.c
+ -> Seq Scan on public.prt2_l_p1
+ Output: prt2_l_p1.b, prt2_l_p1.c
+ Filter: ((prt2_l_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c, prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Hash Cond: ((prt1_l_p2_p1.a = prt2_l_p2_p1.b) AND ((prt1_l_p2_p1.c)::text = (prt2_l_p2_p1.c)::text))
+ -> Seq Scan on public.prt1_l_p2_p1
+ Output: prt1_l_p2_p1.a, prt1_l_p2_p1.c
+ Filter: ((prt1_l_p2_p1.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ -> Seq Scan on public.prt2_l_p2_p1
+ Output: prt2_l_p2_p1.b, prt2_l_p2_p1.c
+ Filter: ((prt2_l_p2_p1.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c, prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Hash Cond: ((prt1_l_p2_p2.a = prt2_l_p2_p2.b) AND ((prt1_l_p2_p2.c)::text = (prt2_l_p2_p2.c)::text))
+ -> Seq Scan on public.prt1_l_p2_p2
+ Output: prt1_l_p2_p2.a, prt1_l_p2_p2.c
+ Filter: ((prt1_l_p2_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ -> Seq Scan on public.prt2_l_p2_p2
+ Output: prt2_l_p2_p2.b, prt2_l_p2_p2.c
+ Filter: ((prt2_l_p2_p2.b % 25) = 0)
+ -> Hash Full Join
+ Output: prt1_l_p3.a, prt1_l_p3.c, prt2_l_p3.b, prt2_l_p3.c
+ Hash Cond: ((prt1_l_p3.a = prt2_l_p3.b) AND ((prt1_l_p3.c)::text = (prt2_l_p3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt1_l_p3
+ Output: prt1_l_p3.a, prt1_l_p3.c
+ Filter: ((prt1_l_p3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1
+ Output: prt1_l_p3_p1.a, prt1_l_p3_p1.c
+ Filter: ((prt1_l_p3_p1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2
+ Output: prt1_l_p3_p2.a, prt1_l_p3_p2.c
+ Filter: ((prt1_l_p3_p2.a % 25) = 0)
+ -> Hash
+ Output: prt2_l_p3.b, prt2_l_p3.c
+ -> Append
+ -> Seq Scan on public.prt2_l_p3
+ Output: prt2_l_p3.b, prt2_l_p3.c
+ Filter: ((prt2_l_p3.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p1
+ Output: prt2_l_p3_p1.b, prt2_l_p3_p1.c
+ Filter: ((prt2_l_p3_p1.b % 25) = 0)
+ -> Seq Scan on public.prt2_l_p3_p2
+ Output: prt2_l_p3_p2.b, prt2_l_p3_p2.c
+ Filter: ((prt2_l_p3_p2.b % 25) = 0)
+(62 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE uprt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l WHERE uprt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+ a | c | b | c
+-----+------+-----+------
+ 0 | 0000 | 0 | 0000
+ 50 | 0050 | |
+ 100 | 0100 | |
+ 150 | 0150 | 150 | 0150
+ 200 | 0200 | |
+ 250 | 0250 | |
+ 300 | 0300 | 300 | 0300
+ 350 | 0350 | |
+ 400 | 0400 | |
+ 450 | 0450 | 450 | 0450
+ 500 | 0500 | |
+ 550 | 0550 | |
+ | | 75 | 0075
+ | | 225 | 0225
+ | | 375 | 0375
+ | | 525 | 0525
+(16 rows)
+
+-- lateral partition-wise join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Result
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a))
+ -> Seq Scan on public.prt1_l_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Hash Join
+ Output: t2.a, t2.c, t2.b, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: ((t3.b = t2.a) AND ((t3.c)::text = (t2.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t2.a, t2.c, t2.b
+ -> Seq Scan on public.prt1_l_p1 t2
+ Output: t2.a, t2.c, t2.b
+ Filter: ((t1.a = t2.a) AND ((t1.c)::text = (t2.c)::text))
+ -> Nested Loop Left Join
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.c, t2_1.b, t3_1.a, (LEAST(t1_1.a, t2_1.a, t3_1.a))
+ -> Seq Scan on public.prt1_l_p2_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Hash Join
+ Output: t2_1.a, t2_1.c, t2_1.b, t3_1.a, LEAST(t1_1.a, t2_1.a, t3_1.a)
+ Hash Cond: ((t3_1.b = t2_1.a) AND ((t3_1.c)::text = (t2_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t2_1.a, t2_1.c, t2_1.b
+ -> Seq Scan on public.prt1_l_p2_p1 t2_1
+ Output: t2_1.a, t2_1.c, t2_1.b
+ Filter: ((t1_1.a = t2_1.a) AND ((t1_1.c)::text = (t2_1.c)::text))
+ -> Nested Loop Left Join
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.c, t2_2.b, t3_2.a, (LEAST(t1_2.a, t2_2.a, t3_2.a))
+ -> Seq Scan on public.prt1_l_p2_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Hash Join
+ Output: t2_2.a, t2_2.c, t2_2.b, t3_2.a, LEAST(t1_2.a, t2_2.a, t3_2.a)
+ Hash Cond: ((t3_2.b = t2_2.a) AND ((t3_2.c)::text = (t2_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t2_2.a, t2_2.c, t2_2.b
+ -> Seq Scan on public.prt1_l_p2_p2 t2_2
+ Output: t2_2.a, t2_2.c, t2_2.b
+ Filter: ((t1_2.a = t2_2.a) AND ((t1_2.c)::text = (t2_2.c)::text))
+ -> Nested Loop Left Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.c, t2_3.b, t3_3.a, (LEAST(t1_3.a, t2_3.a, t3_3.a))
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_4
+ Output: t1_4.a, t1_4.b, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_5
+ Output: t1_5.a, t1_5.b, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+ -> Hash Join
+ Output: t2_3.a, t2_3.c, t2_3.b, t3_3.a, LEAST(t1_3.a, t2_3.a, t3_3.a)
+ Hash Cond: ((t3_3.b = t2_3.a) AND ((t3_3.c)::text = (t2_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t3_3
+ Output: t3_3.a, t3_3.b, t3_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t3_4
+ Output: t3_4.a, t3_4.b, t3_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t3_5
+ Output: t3_5.a, t3_5.b, t3_5.c
+ -> Hash
+ Output: t2_3.a, t2_3.c, t2_3.b
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t2_3
+ Output: t2_3.a, t2_3.c, t2_3.b
+ Filter: ((t1_3.a = t2_3.a) AND ((t1_3.c)::text = (t2_3.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p1 t2_4
+ Output: t2_4.a, t2_4.c, t2_4.b
+ Filter: ((t1_3.a = t2_4.a) AND ((t1_3.c)::text = (t2_4.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p2 t2_5
+ Output: t2_5.a, t2_5.c, t2_5.b
+ Filter: ((t1_3.a = t2_5.a) AND ((t1_3.c)::text = (t2_5.c)::text))
+(85 rows)
+
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
+-- lateral references with clauses without equi-join on partition key
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ Sort Key: t1.a
+ -> Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, t2.a, t2.c, t2.b, t3.a, (LEAST(t1.a, t2.a, t3.a)), t1.a
+ -> Append
+ -> Seq Scan on public.prt1_l t1
+ Output: t1.a, t1.b, t1.c
+ Filter: ((t1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: ((t1_1.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: ((t1_2.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p1 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p2_p2 t1_4
+ Output: t1_4.a, t1_4.b, t1_4.c
+ Filter: ((t1_4.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3 t1_5
+ Output: t1_5.a, t1_5.b, t1_5.c
+ Filter: ((t1_5.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p1 t1_6
+ Output: t1_6.a, t1_6.b, t1_6.c
+ Filter: ((t1_6.a % 25) = 0)
+ -> Seq Scan on public.prt1_l_p3_p2 t1_7
+ Output: t1_7.a, t1_7.b, t1_7.c
+ Filter: ((t1_7.a % 25) = 0)
+ -> Append
+ -> Hash Join
+ Output: t2.a, t2.c, t2.b, t3.a, LEAST(t1.a, t2.a, t3.a)
+ Hash Cond: ((t3.b = t2.a) AND ((t3.c)::text = (t2.c)::text))
+ -> Seq Scan on public.prt2_l_p1 t3
+ Output: t3.a, t3.b, t3.c
+ -> Hash
+ Output: t2.a, t2.c, t2.b
+ -> Seq Scan on public.prt1_l_p1 t2
+ Output: t2.a, t2.c, t2.b
+ Filter: ((t1.b = t2.a) AND ((t1.c)::text = (t2.c)::text))
+ -> Hash Join
+ Output: t2_1.a, t2_1.c, t2_1.b, t3_1.a, LEAST(t1.a, t2_1.a, t3_1.a)
+ Hash Cond: ((t3_1.b = t2_1.a) AND ((t3_1.c)::text = (t2_1.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p1 t3_1
+ Output: t3_1.a, t3_1.b, t3_1.c
+ -> Hash
+ Output: t2_1.a, t2_1.c, t2_1.b
+ -> Seq Scan on public.prt1_l_p2_p1 t2_1
+ Output: t2_1.a, t2_1.c, t2_1.b
+ Filter: ((t1.b = t2_1.a) AND ((t1.c)::text = (t2_1.c)::text))
+ -> Hash Join
+ Output: t2_2.a, t2_2.c, t2_2.b, t3_2.a, LEAST(t1.a, t2_2.a, t3_2.a)
+ Hash Cond: ((t3_2.b = t2_2.a) AND ((t3_2.c)::text = (t2_2.c)::text))
+ -> Seq Scan on public.prt2_l_p2_p2 t3_2
+ Output: t3_2.a, t3_2.b, t3_2.c
+ -> Hash
+ Output: t2_2.a, t2_2.c, t2_2.b
+ -> Seq Scan on public.prt1_l_p2_p2 t2_2
+ Output: t2_2.a, t2_2.c, t2_2.b
+ Filter: ((t1.b = t2_2.a) AND ((t1.c)::text = (t2_2.c)::text))
+ -> Hash Join
+ Output: t2_3.a, t2_3.c, t2_3.b, t3_3.a, LEAST(t1.a, t2_3.a, t3_3.a)
+ Hash Cond: ((t3_3.b = t2_3.a) AND ((t3_3.c)::text = (t2_3.c)::text))
+ -> Append
+ -> Seq Scan on public.prt2_l_p3 t3_3
+ Output: t3_3.a, t3_3.b, t3_3.c
+ -> Seq Scan on public.prt2_l_p3_p1 t3_4
+ Output: t3_4.a, t3_4.b, t3_4.c
+ -> Seq Scan on public.prt2_l_p3_p2 t3_5
+ Output: t3_5.a, t3_5.b, t3_5.c
+ -> Hash
+ Output: t2_3.a, t2_3.c, t2_3.b
+ -> Append
+ -> Seq Scan on public.prt1_l_p3 t2_3
+ Output: t2_3.a, t2_3.c, t2_3.b
+ Filter: ((t1.b = t2_3.a) AND ((t1.c)::text = (t2_3.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p1 t2_4
+ Output: t2_4.a, t2_4.c, t2_4.b
+ Filter: ((t1.b = t2_4.a) AND ((t1.c)::text = (t2_4.c)::text))
+ -> Seq Scan on public.prt1_l_p3_p2 t2_5
+ Output: t2_5.a, t2_5.c, t2_5.b
+ Filter: ((t1.b = t2_5.a) AND ((t1.c)::text = (t2_5.c)::text))
+(83 rows)
+
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+ a | b | c | t2a | t2c | t2b | t3a | least
+-----+-----+------+-----+------+-----+-----+-------
+ 0 | 0 | 0000 | 0 | 0000 | 0 | 0 | 0
+ 50 | 50 | 0050 | | | | |
+ 100 | 100 | 0100 | | | | |
+ 150 | 150 | 0150 | 150 | 0150 | 150 | 150 | 150
+ 200 | 200 | 0200 | | | | |
+ 250 | 250 | 0250 | | | | |
+ 300 | 300 | 0300 | 300 | 0300 | 300 | 300 | 300
+ 350 | 350 | 0350 | | | | |
+ 400 | 400 | 0400 | | | | |
+ 450 | 450 | 0450 | 450 | 0450 | 450 | 450 | 450
+ 500 | 500 | 0500 | | | | |
+ 550 | 550 | 0550 | | | | |
+(12 rows)
+
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index ac38f50..8d28203 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -103,7 +103,7 @@ test: publication subscription
# ----------
# Another group of parallel tests
# ----------
-test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join
+test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb json_encoding indirect_toast equivclass partition_join multi_level_partition_join
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,
diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule
index 1bf98a4..14df5ee 100644
--- a/src/test/regress/serial_schedule
+++ b/src/test/regress/serial_schedule
@@ -173,3 +173,4 @@ test: xml
test: event_trigger
test: stats
test: partition_join
+test: multi_level_partition_join
diff --git a/src/test/regress/sql/multi_level_partition_join.sql b/src/test/regress/sql/multi_level_partition_join.sql
new file mode 100644
index 0000000..821c095
--- /dev/null
+++ b/src/test/regress/sql/multi_level_partition_join.sql
@@ -0,0 +1,95 @@
+-- Encourage partition-wise join plans.
+SET partition_wise_plan_weight TO 0.1;
+
+--
+-- multi-leveled partitions
+--
+CREATE TABLE prt1_l (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE prt1_l_p1 PARTITION OF prt1_l FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt1_l_p2 PARTITION OF prt1_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt1_l_p2_p1 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt1_l_p2_p2 PARTITION OF prt1_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt1_l_p3 PARTITION OF prt1_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (b);
+CREATE TABLE prt1_l_p3_p1 PARTITION OF prt1_l_p3 FOR VALUES FROM (500) TO (550);
+CREATE TABLE prt1_l_p3_p2 PARTITION OF prt1_l_p3 FOR VALUES FROM (550) TO (600);
+INSERT INTO prt1_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 2) i;
+ANALYZE prt1_l;
+ANALYZE prt1_l_p1;
+ANALYZE prt1_l_p2;
+ANALYZE prt1_l_p2_p1;
+ANALYZE prt1_l_p2_p2;
+ANALYZE prt1_l_p3;
+ANALYZE prt1_l_p3_p1;
+ANALYZE prt1_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt1_l AS SELECT * FROM prt1_l;
+
+CREATE TABLE prt2_l (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE prt2_l_p1 PARTITION OF prt2_l FOR VALUES FROM (0) TO (250);
+CREATE TABLE prt2_l_p2 PARTITION OF prt2_l FOR VALUES FROM (250) TO (500) PARTITION BY RANGE (c);
+CREATE TABLE prt2_l_p2_p1 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0250') TO ('0400');
+CREATE TABLE prt2_l_p2_p2 PARTITION OF prt2_l_p2 FOR VALUES FROM ('0400') TO ('0500');
+CREATE TABLE prt2_l_p3 PARTITION OF prt2_l FOR VALUES FROM (500) TO (600) PARTITION BY RANGE (a);
+CREATE TABLE prt2_l_p3_p1 PARTITION OF prt2_l_p3 FOR VALUES FROM (500) TO (525);
+CREATE TABLE prt2_l_p3_p2 PARTITION OF prt2_l_p3 FOR VALUES FROM (525) TO (600);
+INSERT INTO prt2_l SELECT i, i, to_char(i, 'FM0000') FROM generate_series(0, 599, 3) i;
+ANALYZE prt2_l;
+ANALYZE prt2_l_p1;
+ANALYZE prt2_l_p2;
+ANALYZE prt2_l_p2_p1;
+ANALYZE prt2_l_p2_p2;
+ANALYZE prt2_l_p3;
+ANALYZE prt2_l_p3_p1;
+ANALYZE prt2_l_p3_p2;
+-- TODO: This table is created only for testing the results. Remove once
+-- results are tested.
+CREATE TABLE uprt2_l AS SELECT * FROM prt2_l;
+
+-- inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1, prt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1, uprt2_l t2 WHERE t1.a = t2.b AND t1.c = t2.c AND t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- left join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 LEFT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 LEFT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t1.a % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- right join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_l t1 RIGHT JOIN prt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM uprt1_l t1 RIGHT JOIN uprt2_l t2 ON t1.a = t2.b AND t1.c = t2.c WHERE t2.b % 25 = 0 ORDER BY t1.a, t2.b;
+
+-- full join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1_l WHERE prt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM prt2_l WHERE prt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM uprt1_l WHERE uprt1_l.a % 25 = 0) t1 FULL JOIN (SELECT * FROM uprt2_l WHERE uprt2_l.b % 25 = 0) t2 ON (t1.a = t2.b AND t1.c = t2.c) ORDER BY t1.a, t2.b;
+
+-- lateral partition-wise join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.a = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+
+-- lateral references with clauses without equi-join on partition key
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM prt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM prt1_l t2 JOIN prt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
+SELECT * FROM uprt1_l t1 LEFT JOIN LATERAL
+ (SELECT t2.a AS t2a, t2.c AS t2c, t2.b AS t2b, t3.a AS t3a, least(t1.a,t2.a,t3.a) FROM uprt1_l t2 JOIN uprt2_l t3 ON (t2.a = t3.b AND t2.c = t3.c)) ss
+ ON t1.b = ss.t2a AND t1.c = ss.t2c WHERE t1.a % 25 = 0 ORDER BY t1.a;
--
1.7.9.5
0014-Multi-level-partition-wise-join-support.patchapplication/octet-stream; name=0014-Multi-level-partition-wise-join-support.patchDownload
From fb2e5be3de7e1917bce3b1fdd76058aeac13a41f Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Fri, 10 Feb 2017 14:08:16 +0530
Subject: [PATCH 14/14] Multi-level partition-wise join support.
Annotate RelOptInfos of partitioned table by partitioning scheme at all levels
of a partitioning hierarchy.
Also, while creating Merge/Append plans from PartitionJoinPaths flattern
Merge/Append subplans arising from multi-level partitioning hierarchy.
The path to be reparameterized by a child refers to the parameters from the
topmost parent. This parent can be multiple levels away from the given child.
Hence use multi-level expression adjustment routines in
reparameterize_path_by_child().
---
src/backend/optimizer/plan/createplan.c | 27 ++++-
src/backend/optimizer/prep/prepunion.c | 36 +++++--
src/backend/optimizer/util/pathnode.c | 175 +++++++++++++++++++++++++++----
src/backend/optimizer/util/plancat.c | 16 ---
src/include/nodes/relation.h | 6 ++
5 files changed, 217 insertions(+), 43 deletions(-)
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 3f1f2c1..f756be6 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -30,6 +30,7 @@
#include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/paths.h"
+#include "optimizer/pathnode.h"
#include "optimizer/placeholder.h"
#include "optimizer/plancat.h"
#include "optimizer/planmain.h"
@@ -4115,6 +4116,18 @@ create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
best_path->path.pathkeys,
NULL,
TOTAL_COST);
+ else if (best_path->reparamterized_by)
+ {
+ child_path = get_cheapest_parameterized_child_path(root,
+ child_join,
+ best_path->old_param);
+
+ if (!child_path)
+ elog(ERROR, "Could not find a child-join path with required pathkeys or parameterization.");
+
+ child_path = reparameterize_path_by_child(root, child_path,
+ best_path->reparamterized_by);
+ }
else
child_path = get_cheapest_parameterized_child_path(root,
child_join,
@@ -4173,7 +4186,19 @@ create_partition_join_plan(PlannerInfo *root, PartitionJoinPath *best_path)
}
}
- child_plans = lappend(child_plans, child_plan);
+ /* Flatten Merge/Append plans. */
+ if (IsA(child_plan, Append))
+ {
+ Append *append = (Append *) child_plan;
+ child_plans = list_concat(child_plans, append->appendplans);
+ }
+ else if (IsA(child_plan, MergeAppend))
+ {
+ MergeAppend *mappend = (MergeAppend *) child_plan;
+ child_plans = list_concat(child_plans, mappend->mergeplans);
+ }
+ else
+ child_plans = lappend(child_plans, child_plan);
/*
* Reset the child_join memory context to reclaim the memory consumed
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 63b45d6..9399050 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -2183,23 +2183,47 @@ adjust_inherited_tlist(List *tlist, AppendRelInfo *context)
* adjust_appendrel_attrs_multilevel
* Apply Var translations from a toplevel appendrel parent down to a child.
*
- * In some cases we need to translate expressions referencing a baserel
+ * In some cases we need to translate expressions referencing a parent relation
* to reference an appendrel child that's multiple levels removed from it.
*/
Node *
adjust_appendrel_attrs_multilevel(PlannerInfo *root, Node *node,
RelOptInfo *child_rel)
{
- AppendRelInfo *appinfo = find_childrel_appendrelinfo(root, child_rel);
- RelOptInfo *parent_rel = find_base_rel(root, appinfo->parent_relid);
+ List *appinfos = find_appinfos_by_relids(root, child_rel->relids);
+ RelOptInfo *parent_rel;
+
+ if (child_rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ {
+ AppendRelInfo *appinfo = linitial(appinfos);
+ parent_rel = find_base_rel(root, appinfo->parent_relid);
+ }
+ else
+ {
+ Relids parent_relids = NULL;
+ ListCell *lc;
+
+ /* Construct relids set for the immediate parent of the given child. */
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ parent_relids = bms_add_member(parent_relids, appinfo->parent_relid);
+ }
+
+ parent_rel = find_join_rel(root, parent_relids);
+ bms_free(parent_relids);
+ }
/* If parent is also a child, first recurse to apply its translations */
- if (parent_rel->reloptkind == RELOPT_OTHER_MEMBER_REL)
+ if (IS_OTHER_REL(parent_rel))
node = adjust_appendrel_attrs_multilevel(root, node, parent_rel);
else
- Assert(parent_rel->reloptkind == RELOPT_BASEREL);
+ Assert(parent_rel->reloptkind == RELOPT_BASEREL ||
+ parent_rel->reloptkind == RELOPT_JOINREL);
+
/* Now translate for this child */
- return adjust_appendrel_attrs(root, node, list_make1(appinfo));
+ return adjust_appendrel_attrs(root, node, appinfos);
}
/*
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index d1ee237..a32ef1a 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -48,6 +48,11 @@ typedef enum
#define STD_FUZZ_FACTOR 1.01
static List *translate_sub_tlist(List *tlist, int relid);
+static Relids adjust_child_relids_multilevel(PlannerInfo *root, Relids relids,
+ Relids child_relids,
+ Relids top_parent_relids);
+static List *build_child_clauses_multilevel(PlannerInfo *root, List *clauses,
+ Relids child_relids, Relids top_parent_relids);
/*****************************************************************************
@@ -3410,7 +3415,6 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
Path *new_path;
ParamPathInfo *new_ppi;
ParamPathInfo *old_ppi;
- List *child_aris;
Relids required_outer;
/*
@@ -3453,6 +3457,11 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
memcpy(new_path, path, sizeof(AppendPath));
break;
+ case T_PartitionJoinPath:
+ new_path = (Path *) makeNode(PartitionJoinPath);
+ memcpy(new_path, path, sizeof(PartitionJoinPath));
+ break;
+
/*
* TODO:
* If this method of translation is fine add more path types here.
@@ -3464,15 +3473,15 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
}
/*
- * Gather AppendRelInfos of the base partition relations in the outer child
- * relation. We need those for translating parent path to that of child by
- * substituting parent Var nodes and relids with those of children.
+ * Adjust the parameterization information, which refers to the topmost
+ * parent. The topmost parent can be multiple levels away from the given
+ * child, hence use multi-level expression adjustment routines.
*/
- child_aris = find_appinfos_by_relids(root, child_rel->relids);
-
- /* Adjust the parameterization information. */
old_ppi = new_path->param_info;
- required_outer = adjust_child_relids(old_ppi->ppi_req_outer, child_aris);
+ required_outer = adjust_child_relids_multilevel(root,
+ old_ppi->ppi_req_outer,
+ child_rel->relids,
+ child_rel->top_parent_relids);
/* If we already have a PPI for this parameterization, just return it */
new_ppi = find_param_path_info(new_path->parent, required_outer);
@@ -3483,8 +3492,10 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
new_ppi = makeNode(ParamPathInfo);
new_ppi->ppi_req_outer = required_outer;
new_ppi->ppi_rows = old_ppi->ppi_rows;
- new_ppi->ppi_clauses = build_child_clauses(root, old_ppi->ppi_clauses,
- child_aris);
+ new_ppi->ppi_clauses = build_child_clauses_multilevel(root,
+ old_ppi->ppi_clauses,
+ child_rel->relids,
+ child_rel->top_parent_relids);
new_path->parent->ppilist = lappend(new_path->parent->ppilist, new_ppi);
}
else
@@ -3500,6 +3511,7 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
if (bms_overlap(path->parent->lateral_relids, child_rel->top_parent_relids))
{
MemoryContext old_context;
+ List *exprs;
/*
* Allocate the target in planner's context, since they are copied as
@@ -3507,9 +3519,12 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
*/
old_context = MemoryContextSwitchTo(root->planner_cxt);
new_path->pathtarget = copy_pathtarget(new_path->pathtarget);
- new_path->pathtarget->exprs = (List *) adjust_appendrel_attrs(root,
- (Node *) new_path->pathtarget->exprs,
- child_aris);
+ exprs = new_path->pathtarget->exprs;
+ exprs = (List *) adjust_appendrel_attrs_multilevel(root,
+ (Node *) exprs,
+ child_rel);
+ new_path->pathtarget->exprs = exprs;
+
MemoryContextSwitchTo(old_context);
}
@@ -3531,9 +3546,10 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
jpath->innerjoinpath = reparameterize_path_by_child(root,
jpath->innerjoinpath,
child_rel);
- jpath->joinrestrictinfo = build_child_clauses(root,
- jpath->joinrestrictinfo,
- child_aris);
+ jpath->joinrestrictinfo = build_child_clauses_multilevel(root,
+ jpath->joinrestrictinfo,
+ child_rel->relids,
+ child_rel->top_parent_relids);
}
break;
@@ -3556,10 +3572,30 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
{
IndexPath *ipath = (IndexPath *)new_path;
- ipath->indexclauses = build_child_clauses(root, ipath->indexclauses,
- child_aris);
- ipath->indexquals = build_child_clauses(root, ipath->indexquals,
- child_aris);
+ ipath->indexclauses = build_child_clauses_multilevel(root,
+ ipath->indexclauses,
+ child_rel->relids,
+ child_rel->top_parent_relids);
+
+ ipath->indexquals = build_child_clauses_multilevel(root,
+ ipath->indexquals,
+ child_rel->relids,
+ child_rel->top_parent_relids);
+ }
+ break;
+
+ case T_PartitionJoinPath:
+ {
+ PartitionJoinPath *pjpath = (PartitionJoinPath *)new_path;
+
+ /*
+ * The paths for the child-joins covered by PartitionJoinPath will
+ * be created later. If this PartitionJoinPath was reparameterized
+ * by child of another relations, we will need that relation to
+ * reparamterize the child-join paths.
+ */
+ pjpath->old_param = PATH_REQ_OUTER(path);
+ pjpath->reparamterized_by = child_rel;
}
break;
@@ -3570,3 +3606,102 @@ reparameterize_path_by_child(PlannerInfo *root, Path *path,
return new_path;
}
+
+/*
+ * Replace any relid present in top_parent_relids with its child in
+ * child_relids. Members of child_relids can be multiple levels below top
+ * parent in the partition hierarchy.
+ */
+Relids
+adjust_child_relids_multilevel(PlannerInfo *root, Relids relids,
+ Relids child_relids, Relids top_parent_relids)
+{
+ List *appinfos;
+ Relids parent_relids = NULL;
+ ListCell *lc;
+ Relids result;
+ Relids tmp_result = NULL;
+
+ /*
+ * If the given relids set doesn't contain any of the top parent relids,
+ * it will remain unchanged.
+ */
+ if (!bms_overlap(relids, top_parent_relids))
+ return relids;
+
+ appinfos = find_appinfos_by_relids(root, child_relids);
+
+ /* Construct relids set for the immediate parent of the given child. */
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ parent_relids = bms_add_member(parent_relids, appinfo->parent_relid);
+ }
+
+ /* Recurse if immediate parent is not the top parent. */
+ if (!bms_equal(parent_relids, top_parent_relids))
+ {
+ tmp_result = adjust_child_relids_multilevel(root, relids,
+ parent_relids,
+ top_parent_relids);
+ relids = tmp_result;
+ }
+
+ result = adjust_child_relids(relids, appinfos);
+
+ /* Free memory consumed by any immediate result. */
+ if (tmp_result)
+ bms_free(tmp_result);
+
+ bms_free(parent_relids);
+ list_free(appinfos);
+ return result;
+}
+
+/*
+ * build_child_clauses_multilevel
+ * Similar to build_child_clauses but used when the child relation
+ * represented by child_relids is
+ * deeper down in the partition hierarchy reprepresented by parent
+ * relation with relids top_parent_relids.
+ */
+List *
+build_child_clauses_multilevel(PlannerInfo *root, List *clauses,
+ Relids child_relids, Relids top_parent_relids)
+{
+ List *appinfos;
+ Relids parent_relids = NULL;
+ ListCell *lc;
+ List *result;
+ List *tmp_result = NIL;
+
+ appinfos = find_appinfos_by_relids(root, child_relids);
+
+ /* Construct relids set for the immediate parent of the given child. */
+ foreach (lc, appinfos)
+ {
+ AppendRelInfo *appinfo = lfirst(lc);
+
+ parent_relids = bms_add_member(parent_relids, appinfo->parent_relid);
+ }
+
+ /* Recurse if immediate parent is not the top parent. */
+ if (!bms_equal(parent_relids, top_parent_relids))
+ {
+ clauses = build_child_clauses_multilevel(root, clauses, parent_relids,
+ top_parent_relids);
+ tmp_result = clauses;
+ }
+
+ result = build_child_clauses(root, clauses, appinfos);
+
+ /* Free memory consumed by any itermediate list. */
+ if (tmp_result)
+ list_free(tmp_result);
+
+ bms_free(parent_relids);
+ list_free(appinfos);
+
+ return result;
+}
diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c
index 01ba885..c5e0ebf 100644
--- a/src/backend/optimizer/util/plancat.c
+++ b/src/backend/optimizer/util/plancat.c
@@ -1787,7 +1787,6 @@ find_partition_scheme(PlannerInfo *root, Relation relation)
int nparts;
int partnatts;
int cnt_pks;
- int cnt_parts;
PartitionScheme part_scheme = NULL;
/* No partition scheme for an unpartitioned relation. */
@@ -1797,21 +1796,6 @@ find_partition_scheme(PlannerInfo *root, Relation relation)
nparts = part_desc->nparts;
partnatts = part_key->partnatts;
- /*
- * For a multi-level partitioned table, we do not retain the partitioning
- * hierarchy while expanding RTE for the topmost parent. Thus the number of
- * children as per root->append_rel_list does not match the number of
- * partitions specified in the partition descriptor and hence the
- * partitioning scheme of a multi-partitioned table does not reflect the
- * true picture. So for now, treat a multi-partitioned table as not
- * partitioned.
- */
- for (cnt_parts = 0; cnt_parts < nparts; cnt_parts++)
- {
- if (has_subclass(part_desc->oids[cnt_parts]))
- return NULL;
- }
-
/* Search for a matching partition scheme and return if found one. */
foreach (lc, root->part_schemes)
{
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index 146d53b..f1ae325 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -1569,6 +1569,12 @@ typedef struct LimitPath
typedef struct PartitionJoinPath
{
Path path;
+
+ /* If this path is result of reparameterization by child. */
+ Relids old_param; /* Older parameterization. */
+ RelOptInfo *reparamterized_by; /* Child relation by which this paths was
+ * reparamterized.
+ */
} PartitionJoinPath;
/*
--
1.7.9.5
On Mon, Feb 6, 2017 at 3:34 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
PartitionScheme is shared across multiple relations, join or base,
partitioned similarly. Obviously it can't and does not need to point
partition bound informations (which should all be same) of all those
base relations. O the the face of it, it looks weird that it points to
only one of them, mostly the one which it encounters first. But, since
it's going to be the same partition bound information, it doesn't
matter which one. So, I think, we can point of any one of those. Do
you agree?
Yes.
The fact that set_append_rel_size needs to reopen the relation to
extract a few more bits of information is not desirable. You need to
fish this information through in some other way; for example, you
could have get_relation_info() stash the needed bits in the
RelOptInfo.I considered this option and discarded it, since not all partitioned
relations will have OIDs for partitions e.g. partitioned joins will
not have OIDs for their partitions. But now that I think of it, we
should probably store those OIDs just for the base relation and leave
them unused for non-base relations just like other base relation
specific fields in RelOptInfo.
Right.
FRACTION_PARTS_TO_PLAN seems like it should be a GUC.
+1. Will take care of this. Does "representative_partitions_fraction"
or "sample_partition_fraction" look like a good GUC name? Any other
suggestions?
I like the second one.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
2. If the PartitionJoinPath emerges as the best path, we create paths
for each of the remaining child-joins. Then we collect paths with
properties same as the given PartitionJoinPath, one from each
child-join. These paths are converted into plans and a Merge/Append
plan is created combing these plans. The paths and plans for
child-join are created in a temporary memory context. The final plan
for each child-join is copied into planner's context and the temporary
memory context is reset.
Robert and I discussed this in more detail. Path creation code may
allocate objects other than paths. postgres_fdw, for example,
allocates character array to hold the name of relation being
pushed-down. When the temporary context gets zapped after creating
paths for a given child-join, those other objects also gets thrown
away. Attached patch has implemented the idea that came out of the
discussion.
We create a memory context for holding paths at the time of creating
PlannerGlobal and save it in PlannerGlobal. The patch introduces a new
macro makePathNode() which allocates the memory for given type of path
from this context. Every create_*_path function has been changed to
use this macro instead of makeNode(). In standard_planner(), at the
end of planning we destroy the memory context freeing all the paths
allocated. While creating a plan node, planner copies everything
required by the plan from the path, so the path is not needed any
more. So, freeing corresponding memory should not have any adverse
effects.
Most of the create_*_path() functions accept root as an argument, thus
the temporary path context is available through root->glob everywhere.
An exception is create_append_path() which does not accept root as an
argument. The patch changes create_append_path() and its callers like
set_dummy_rel_pathlist(), mark_dummy_rel() to accept root as an
argument. Ideally paths are not required after creating plan, so we
should be
able to free the context right after the call to create_plan(). But we
need dummy paths while creating flat rtable in
set_plan_references()->add_rtes_to_flat_rtable(). We used to So free
the path context at the end of planning cycle. Now that we are
allocating all the paths in a different memory context, it doesn't
make sense to switch context in mark_dummy_rel().
0001 patch implements the idea described above.
0002 patch adds instrumentation to measure memory consumed in
standard_planner() call.
0003 patch adds a GUC zap_paths to enable/disable destroying path context.
The last two patches are for testing only.
Attached also find the SQL script and its output showing the memory
saved. For a 5 way self-join of pg_class, the total memory consumed in
standard_planner() is 760K without patch and with patch it comes down
to 713K, saving 47K memory otherwise occupied by paths. It looks like
something useful even without partition-wise joins.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
0001-Free-up-memory-consumed-by-the-paths.patchapplication/octet-stream; name=0001-Free-up-memory-consumed-by-the-paths.patchDownload
From d62d4a40dc52ab05416446d19eaf53125d33aa4b Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 1 Mar 2017 11:07:28 +0530
Subject: [PATCH 1/3] Free up memory consumed by the paths.
Optimizer creates many paths while planning the query. Only one path
tree gets converted to the plan. The memory consumed by paths even
after the plan is created. For a simple query, it means that the
memory remains occupied till the end of the execution. Since plan node
copies the relevant information from the corresponding path, paths are
not needed after plan is created. We can free up that memory.
While creating global planner structure (PlannerGlob) we allocated a
separate memory context for creating paths. Every create_*_path()
function allocates path node in this context. The context is freed at
the end of planning cycle after creating PlannedStmt.
Ideally paths are not required after creating plan, so we should be
able to free the context right after the call to create_plan(). But we
need dummy paths while creating flat rtable in
set_plan_references()->add_rtes_to_flat_rtable(). There might be other
corner cases where we need paths. So free the path context at the end
of planning cycle.
---
src/backend/optimizer/path/allpaths.c | 25 ++++-----
src/backend/optimizer/path/joinpath.c | 2 +-
src/backend/optimizer/path/joinrels.c | 22 ++++----
src/backend/optimizer/plan/planner.c | 16 +++++-
src/backend/optimizer/prep/prepunion.c | 4 +-
src/backend/optimizer/util/pathnode.c | 91 +++++++++++++++++++-------------
src/include/nodes/relation.h | 2 +
src/include/optimizer/pathnode.h | 10 ++--
src/include/optimizer/paths.h | 2 +-
9 files changed, 104 insertions(+), 70 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 633b5c1..e22817e 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -325,7 +325,7 @@ set_rel_size(PlannerInfo *root, RelOptInfo *rel,
* we don't have a convention for marking a rel as dummy except by
* assigning a dummy path to it.
*/
- set_dummy_rel_pathlist(rel);
+ set_dummy_rel_pathlist(root, rel);
}
else if (rte->inh)
{
@@ -769,7 +769,7 @@ set_tablesample_rel_pathlist(PlannerInfo *root, RelOptInfo *rel, RangeTblEntry *
bms_membership(root->all_baserels) != BMS_SINGLETON) &&
!(GetTsmRoutine(rte->tablesample->tsmhandler)->repeatable_across_scans))
{
- path = (Path *) create_material_path(rel, path);
+ path = (Path *) create_material_path(root, rel, path);
}
add_path(rel, path);
@@ -993,7 +993,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* Some restriction clause reduced to constant FALSE or NULL after
* substitution, so this child need not be scanned.
*/
- set_dummy_rel_pathlist(childrel);
+ set_dummy_rel_pathlist(root, childrel);
continue;
}
@@ -1003,7 +1003,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* This child need not be scanned, so we can omit it from the
* appendrel.
*/
- set_dummy_rel_pathlist(childrel);
+ set_dummy_rel_pathlist(root, childrel);
continue;
}
@@ -1153,7 +1153,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* appendrel dummy. We must do this in this phase so that the rel's
* dummy-ness is visible when we generate paths for other rels.
*/
- set_dummy_rel_pathlist(rel);
+ set_dummy_rel_pathlist(root, rel);
}
pfree(parent_attrsizes);
@@ -1314,7 +1314,8 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, subpaths, NULL,
+ 0));
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1340,7 +1341,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Assert(parallel_workers > 0);
/* Generate a partial append path. */
- appendpath = create_append_path(rel, partial_subpaths, NULL,
+ appendpath = create_append_path(root, rel, partial_subpaths, NULL,
parallel_workers);
add_partial_path(rel, (Path *) appendpath);
}
@@ -1392,8 +1393,8 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, subpaths,
+ required_outer, 0));
}
}
@@ -1613,7 +1614,7 @@ accumulate_append_subpath(List *subpaths, Path *path)
* This is exported because inheritance_planner() has need for it.
*/
void
-set_dummy_rel_pathlist(RelOptInfo *rel)
+set_dummy_rel_pathlist(PlannerInfo *root, RelOptInfo *rel)
{
/* Set dummy size estimates --- we leave attr_widths[] as zeroes */
rel->rows = 0;
@@ -1623,7 +1624,7 @@ set_dummy_rel_pathlist(RelOptInfo *rel)
rel->pathlist = NIL;
rel->partial_pathlist = NIL;
- add_path(rel, (Path *) create_append_path(rel, NIL, NULL, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, NIL, NULL, 0));
/*
* We set the cheapest path immediately, to ensure that IS_DUMMY_REL()
@@ -1808,7 +1809,7 @@ set_subquery_pathlist(PlannerInfo *root, RelOptInfo *rel,
if (IS_DUMMY_REL(sub_final_rel))
{
- set_dummy_rel_pathlist(rel);
+ set_dummy_rel_pathlist(root, rel);
return;
}
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index 2897245..2a0f6d9 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -1124,7 +1124,7 @@ match_unsorted_outer(PlannerInfo *root,
if (enable_material && inner_cheapest_total != NULL &&
!ExecMaterializesOutput(inner_cheapest_total->pathtype))
matpath = (Path *)
- create_material_path(innerrel, inner_cheapest_total);
+ create_material_path(root, innerrel, inner_cheapest_total);
}
foreach(lc1, outerrel->pathlist)
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 0d00683..ff493b3 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -29,7 +29,7 @@ static void make_rels_by_clauseless_joins(PlannerInfo *root,
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
-static void mark_dummy_rel(RelOptInfo *rel);
+static void mark_dummy_rel(PlannerInfo *root, RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
@@ -748,7 +748,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) || is_dummy_rel(rel2) ||
restriction_is_constant_false(restrictlist, false))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -762,12 +762,12 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) ||
restriction_is_constant_false(restrictlist, true))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
if (restriction_is_constant_false(restrictlist, false) &&
bms_is_subset(rel2->relids, sjinfo->syn_righthand))
- mark_dummy_rel(rel2);
+ mark_dummy_rel(root, rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_LEFT, sjinfo,
restrictlist);
@@ -779,7 +779,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if ((is_dummy_rel(rel1) && is_dummy_rel(rel2)) ||
restriction_is_constant_false(restrictlist, true))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -815,7 +815,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) || is_dummy_rel(rel2) ||
restriction_is_constant_false(restrictlist, false))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -838,7 +838,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) || is_dummy_rel(rel2) ||
restriction_is_constant_false(restrictlist, false))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -853,12 +853,12 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) ||
restriction_is_constant_false(restrictlist, true))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
if (restriction_is_constant_false(restrictlist, false) &&
bms_is_subset(rel2->relids, sjinfo->syn_righthand))
- mark_dummy_rel(rel2);
+ mark_dummy_rel(root, rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
@@ -1178,7 +1178,7 @@ is_dummy_rel(RelOptInfo *rel)
* context the given RelOptInfo is in.
*/
static void
-mark_dummy_rel(RelOptInfo *rel)
+mark_dummy_rel(PlannerInfo *root, RelOptInfo *rel)
{
MemoryContext oldcontext;
@@ -1197,7 +1197,7 @@ mark_dummy_rel(RelOptInfo *rel)
rel->partial_pathlist = NIL;
/* Set up the dummy path */
- add_path(rel, (Path *) create_append_path(rel, NIL, NULL, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, NIL, NULL, 0));
/* Set or update cheapest_total_path and related fields */
set_cheapest(rel);
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index ca0ae78..b74e887 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -54,6 +54,7 @@
#include "utils/rel.h"
#include "utils/selfuncs.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
#include "utils/syscache.h"
@@ -218,6 +219,9 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
glob->lastPlanNodeId = 0;
glob->transientPlan = false;
glob->dependsOnRole = false;
+ glob->path_cxt = AllocSetContextCreate(CurrentMemoryContext,
+ "Path creation temporary context",
+ ALLOCSET_DEFAULT_SIZES);
/*
* Assess whether it's feasible to use parallel mode for this query. We
@@ -414,6 +418,13 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
result->stmt_location = parse->stmt_location;
result->stmt_len = parse->stmt_len;
+ /*
+ * We do not need paths any more, blow those away.
+ * TODO: probably we should also set the pathlists to NIL.
+ */
+ MemoryContextResetAndDeleteChildren(glob->path_cxt);
+ glob->path_cxt = NULL;
+
return result;
}
@@ -1302,7 +1313,7 @@ inheritance_planner(PlannerInfo *root)
*/
if (subpaths == NIL)
{
- set_dummy_rel_pathlist(final_rel);
+ set_dummy_rel_pathlist(root, final_rel);
return;
}
@@ -3334,7 +3345,7 @@ create_grouping_paths(PlannerInfo *root,
paths = lappend(paths, path);
}
path = (Path *)
- create_append_path(grouped_rel,
+ create_append_path(root, grouped_rel,
paths,
NULL,
0);
@@ -5261,6 +5272,7 @@ plan_cluster_use_sort(Oid tableOid, Oid indexOid)
query->commandType = CMD_SELECT;
glob = makeNode(PlannerGlobal);
+ glob->path_cxt = CurrentMemoryContext;
root = makeNode(PlannerInfo);
root->parse = query;
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 1389db1..492f8df 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -566,7 +566,7 @@ generate_union_path(SetOperationStmt *op, PlannerInfo *root,
/*
* Append the child results together.
*/
- path = (Path *) create_append_path(result_rel, pathlist, NULL, 0);
+ path = (Path *) create_append_path(root, result_rel, pathlist, NULL, 0);
/* We have to manually jam the right tlist into the path; ick */
path->pathtarget = create_pathtarget(root, tlist);
@@ -678,7 +678,7 @@ generate_nonunion_path(SetOperationStmt *op, PlannerInfo *root,
/*
* Append the child results together.
*/
- path = (Path *) create_append_path(result_rel, pathlist, NULL, 0);
+ path = (Path *) create_append_path(root, result_rel, pathlist, NULL, 0);
/* We have to manually jam the right tlist into the path; ick */
path->pathtarget = create_pathtarget(root, tlist);
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index 3248296..b91b25e 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -928,6 +928,18 @@ add_partial_path_precheck(RelOptInfo *parent_rel, Cost total_cost,
/*****************************************************************************
* PATH NODE CREATION ROUTINES
*****************************************************************************/
+#define makePathNode(root, _type_) ((_type_ *) newPath((root), sizeof(_type_),T_##_type_))
+
+static Path *
+newPath(PlannerInfo *root, size_t size, NodeTag tag)
+{
+ Path *result;
+
+ Assert(sizeof(Path) <= size);
+ result = MemoryContextAllocZero(root->glob->path_cxt, size);
+ result->type = tag;
+ return result;
+}
/*
* create_seqscan_path
@@ -938,7 +950,7 @@ Path *
create_seqscan_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer, int parallel_workers)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_SeqScan;
pathnode->parent = rel;
@@ -962,7 +974,7 @@ create_seqscan_path(PlannerInfo *root, RelOptInfo *rel,
Path *
create_samplescan_path(PlannerInfo *root, RelOptInfo *rel, Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_SampleScan;
pathnode->parent = rel;
@@ -1018,7 +1030,7 @@ create_index_path(PlannerInfo *root,
double loop_count,
bool partial_path)
{
- IndexPath *pathnode = makeNode(IndexPath);
+ IndexPath *pathnode = makePathNode(root, IndexPath);
RelOptInfo *rel = index->rel;
List *indexquals,
*indexqualcols;
@@ -1070,7 +1082,7 @@ create_bitmap_heap_path(PlannerInfo *root,
Relids required_outer,
double loop_count)
{
- BitmapHeapPath *pathnode = makeNode(BitmapHeapPath);
+ BitmapHeapPath *pathnode = makePathNode(root, BitmapHeapPath);
pathnode->path.pathtype = T_BitmapHeapScan;
pathnode->path.parent = rel;
@@ -1100,7 +1112,7 @@ create_bitmap_and_path(PlannerInfo *root,
RelOptInfo *rel,
List *bitmapquals)
{
- BitmapAndPath *pathnode = makeNode(BitmapAndPath);
+ BitmapAndPath *pathnode = makePathNode(root, BitmapAndPath);
pathnode->path.pathtype = T_BitmapAnd;
pathnode->path.parent = rel;
@@ -1136,7 +1148,7 @@ create_bitmap_or_path(PlannerInfo *root,
RelOptInfo *rel,
List *bitmapquals)
{
- BitmapOrPath *pathnode = makeNode(BitmapOrPath);
+ BitmapOrPath *pathnode = makePathNode(root, BitmapOrPath);
pathnode->path.pathtype = T_BitmapOr;
pathnode->path.parent = rel;
@@ -1171,7 +1183,7 @@ TidPath *
create_tidscan_path(PlannerInfo *root, RelOptInfo *rel, List *tidquals,
Relids required_outer)
{
- TidPath *pathnode = makeNode(TidPath);
+ TidPath *pathnode = makePathNode(root, TidPath);
pathnode->path.pathtype = T_TidScan;
pathnode->path.parent = rel;
@@ -1199,10 +1211,13 @@ create_tidscan_path(PlannerInfo *root, RelOptInfo *rel, List *tidquals,
* Note that we must handle subpaths = NIL, representing a dummy access path.
*/
AppendPath *
-create_append_path(RelOptInfo *rel, List *subpaths, Relids required_outer,
+create_append_path(PlannerInfo *root,
+ RelOptInfo *rel,
+ List *subpaths,
+ Relids required_outer,
int parallel_workers)
{
- AppendPath *pathnode = makeNode(AppendPath);
+ AppendPath *pathnode = makePathNode(root, AppendPath);
ListCell *l;
pathnode->path.pathtype = T_Append;
@@ -1259,7 +1274,7 @@ create_merge_append_path(PlannerInfo *root,
List *pathkeys,
Relids required_outer)
{
- MergeAppendPath *pathnode = makeNode(MergeAppendPath);
+ MergeAppendPath *pathnode = makePathNode(root, MergeAppendPath);
Cost input_startup_cost;
Cost input_total_cost;
ListCell *l;
@@ -1346,7 +1361,7 @@ ResultPath *
create_result_path(PlannerInfo *root, RelOptInfo *rel,
PathTarget *target, List *resconstantqual)
{
- ResultPath *pathnode = makeNode(ResultPath);
+ ResultPath *pathnode = makePathNode(root, ResultPath);
pathnode->path.pathtype = T_Result;
pathnode->path.parent = rel;
@@ -1382,9 +1397,9 @@ create_result_path(PlannerInfo *root, RelOptInfo *rel,
* pathnode.
*/
MaterialPath *
-create_material_path(RelOptInfo *rel, Path *subpath)
+create_material_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath)
{
- MaterialPath *pathnode = makeNode(MaterialPath);
+ MaterialPath *pathnode = makePathNode(root, MaterialPath);
Assert(subpath->parent == rel);
@@ -1451,7 +1466,7 @@ create_unique_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
*/
oldcontext = MemoryContextSwitchTo(root->planner_cxt);
- pathnode = makeNode(UniquePath);
+ pathnode = makePathNode(root, UniquePath);
pathnode->path.pathtype = T_Unique;
pathnode->path.parent = rel;
@@ -1667,7 +1682,7 @@ GatherPath *
create_gather_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
PathTarget *target, Relids required_outer, double *rows)
{
- GatherPath *pathnode = makeNode(GatherPath);
+ GatherPath *pathnode = makePathNode(root, GatherPath);
Assert(subpath->parallel_safe);
@@ -1705,7 +1720,7 @@ SubqueryScanPath *
create_subqueryscan_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
List *pathkeys, Relids required_outer)
{
- SubqueryScanPath *pathnode = makeNode(SubqueryScanPath);
+ SubqueryScanPath *pathnode = makePathNode(root, SubqueryScanPath);
pathnode->path.pathtype = T_SubqueryScan;
pathnode->path.parent = rel;
@@ -1733,7 +1748,7 @@ Path *
create_functionscan_path(PlannerInfo *root, RelOptInfo *rel,
List *pathkeys, Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_FunctionScan;
pathnode->parent = rel;
@@ -1759,7 +1774,7 @@ Path *
create_valuesscan_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_ValuesScan;
pathnode->parent = rel;
@@ -1784,7 +1799,7 @@ create_valuesscan_path(PlannerInfo *root, RelOptInfo *rel,
Path *
create_ctescan_path(PlannerInfo *root, RelOptInfo *rel, Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_CteScan;
pathnode->parent = rel;
@@ -1810,7 +1825,7 @@ Path *
create_worktablescan_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_WorkTableScan;
pathnode->parent = rel;
@@ -1849,7 +1864,7 @@ create_foreignscan_path(PlannerInfo *root, RelOptInfo *rel,
Path *fdw_outerpath,
List *fdw_private)
{
- ForeignPath *pathnode = makeNode(ForeignPath);
+ ForeignPath *pathnode = makePathNode(root, ForeignPath);
pathnode->path.pathtype = T_ForeignScan;
pathnode->path.parent = rel;
@@ -1955,7 +1970,7 @@ create_nestloop_path(PlannerInfo *root,
List *pathkeys,
Relids required_outer)
{
- NestPath *pathnode = makeNode(NestPath);
+ NestPath *pathnode = makePathNode(root, NestPath);
Relids inner_req_outer = PATH_REQ_OUTER(inner_path);
/*
@@ -2045,7 +2060,7 @@ create_mergejoin_path(PlannerInfo *root,
List *outersortkeys,
List *innersortkeys)
{
- MergePath *pathnode = makeNode(MergePath);
+ MergePath *pathnode = makePathNode(root, MergePath);
pathnode->jpath.path.pathtype = T_MergeJoin;
pathnode->jpath.path.parent = joinrel;
@@ -2107,7 +2122,7 @@ create_hashjoin_path(PlannerInfo *root,
Relids required_outer,
List *hashclauses)
{
- HashPath *pathnode = makeNode(HashPath);
+ HashPath *pathnode = makePathNode(root, HashPath);
pathnode->jpath.path.pathtype = T_HashJoin;
pathnode->jpath.path.parent = joinrel;
@@ -2164,7 +2179,7 @@ create_projection_path(PlannerInfo *root,
Path *subpath,
PathTarget *target)
{
- ProjectionPath *pathnode = makeNode(ProjectionPath);
+ ProjectionPath *pathnode = makePathNode(root, ProjectionPath);
PathTarget *oldtarget = subpath->pathtarget;
pathnode->path.pathtype = T_Result;
@@ -2331,7 +2346,7 @@ create_set_projection_path(PlannerInfo *root,
Path *subpath,
PathTarget *target)
{
- ProjectSetPath *pathnode = makeNode(ProjectSetPath);
+ ProjectSetPath *pathnode = makePathNode(root, ProjectSetPath);
double tlist_rows;
ListCell *lc;
@@ -2399,7 +2414,7 @@ create_sort_path(PlannerInfo *root,
List *pathkeys,
double limit_tuples)
{
- SortPath *pathnode = makeNode(SortPath);
+ SortPath *pathnode = makePathNode(root, SortPath);
pathnode->path.pathtype = T_Sort;
pathnode->path.parent = rel;
@@ -2445,7 +2460,7 @@ create_group_path(PlannerInfo *root,
List *qual,
double numGroups)
{
- GroupPath *pathnode = makeNode(GroupPath);
+ GroupPath *pathnode = makePathNode(root, GroupPath);
pathnode->path.pathtype = T_Group;
pathnode->path.parent = rel;
@@ -2501,7 +2516,7 @@ create_upper_unique_path(PlannerInfo *root,
int numCols,
double numGroups)
{
- UpperUniquePath *pathnode = makeNode(UpperUniquePath);
+ UpperUniquePath *pathnode = makePathNode(root, UpperUniquePath);
pathnode->path.pathtype = T_Unique;
pathnode->path.parent = rel;
@@ -2558,7 +2573,7 @@ create_agg_path(PlannerInfo *root,
const AggClauseCosts *aggcosts,
double numGroups)
{
- AggPath *pathnode = makeNode(AggPath);
+ AggPath *pathnode = makePathNode(root, AggPath);
pathnode->path.pathtype = T_Agg;
pathnode->path.parent = rel;
@@ -2623,7 +2638,7 @@ create_groupingsets_path(PlannerInfo *root,
const AggClauseCosts *agg_costs,
double numGroups)
{
- GroupingSetsPath *pathnode = makeNode(GroupingSetsPath);
+ GroupingSetsPath *pathnode = makePathNode(root, GroupingSetsPath);
int numGroupCols;
/* The topmost generated Plan node will be an Agg */
@@ -2736,7 +2751,7 @@ create_minmaxagg_path(PlannerInfo *root,
List *mmaggregates,
List *quals)
{
- MinMaxAggPath *pathnode = makeNode(MinMaxAggPath);
+ MinMaxAggPath *pathnode = makePathNode(root, MinMaxAggPath);
Cost initplan_cost;
ListCell *lc;
@@ -2797,7 +2812,7 @@ create_windowagg_path(PlannerInfo *root,
WindowClause *winclause,
List *winpathkeys)
{
- WindowAggPath *pathnode = makeNode(WindowAggPath);
+ WindowAggPath *pathnode = makePathNode(root, WindowAggPath);
pathnode->path.pathtype = T_WindowAgg;
pathnode->path.parent = rel;
@@ -2864,7 +2879,7 @@ create_setop_path(PlannerInfo *root,
double numGroups,
double outputRows)
{
- SetOpPath *pathnode = makeNode(SetOpPath);
+ SetOpPath *pathnode = makePathNode(root, SetOpPath);
pathnode->path.pathtype = T_SetOp;
pathnode->path.parent = rel;
@@ -2924,7 +2939,7 @@ create_recursiveunion_path(PlannerInfo *root,
int wtParam,
double numGroups)
{
- RecursiveUnionPath *pathnode = makeNode(RecursiveUnionPath);
+ RecursiveUnionPath *pathnode = makePathNode(root, RecursiveUnionPath);
pathnode->path.pathtype = T_RecursiveUnion;
pathnode->path.parent = rel;
@@ -2963,7 +2978,7 @@ LockRowsPath *
create_lockrows_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath, List *rowMarks, int epqParam)
{
- LockRowsPath *pathnode = makeNode(LockRowsPath);
+ LockRowsPath *pathnode = makePathNode(root, LockRowsPath);
pathnode->path.pathtype = T_LockRows;
pathnode->path.parent = rel;
@@ -3025,7 +3040,7 @@ create_modifytable_path(PlannerInfo *root, RelOptInfo *rel,
List *rowMarks, OnConflictExpr *onconflict,
int epqParam)
{
- ModifyTablePath *pathnode = makeNode(ModifyTablePath);
+ ModifyTablePath *pathnode = makePathNode(root, ModifyTablePath);
double total_size;
ListCell *lc;
@@ -3120,7 +3135,7 @@ create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est)
{
- LimitPath *pathnode = makeNode(LimitPath);
+ LimitPath *pathnode = makePathNode(root, LimitPath);
pathnode->path.pathtype = T_Limit;
pathnode->path.parent = rel;
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index f7ac6f6..aa2e9b3 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -128,6 +128,8 @@ typedef struct PlannerGlobal
bool parallelModeNeeded; /* parallel mode actually required? */
char maxParallelHazard; /* worst PROPARALLEL hazard level */
+
+ MemoryContext path_cxt; /* Temporary context for holding paths. */
} PlannerGlobal;
/* macro for fetching the Plan associated with a SubPlan node */
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 53cad24..18591df 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -62,8 +62,11 @@ extern BitmapOrPath *create_bitmap_or_path(PlannerInfo *root,
List *bitmapquals);
extern TidPath *create_tidscan_path(PlannerInfo *root, RelOptInfo *rel,
List *tidquals, Relids required_outer);
-extern AppendPath *create_append_path(RelOptInfo *rel, List *subpaths,
- Relids required_outer, int parallel_workers);
+extern AppendPath *create_append_path(PlannerInfo *root,
+ RelOptInfo *rel,
+ List *subpaths,
+ Relids required_outer,
+ int parallel_workers);
extern MergeAppendPath *create_merge_append_path(PlannerInfo *root,
RelOptInfo *rel,
List *subpaths,
@@ -71,7 +74,8 @@ extern MergeAppendPath *create_merge_append_path(PlannerInfo *root,
Relids required_outer);
extern ResultPath *create_result_path(PlannerInfo *root, RelOptInfo *rel,
PathTarget *target, List *resconstantqual);
-extern MaterialPath *create_material_path(RelOptInfo *rel, Path *subpath);
+extern MaterialPath *create_material_path(PlannerInfo *root, RelOptInfo *rel,
+ Path *subpath);
extern UniquePath *create_unique_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath, SpecialJoinInfo *sjinfo);
extern GatherPath *create_gather_path(PlannerInfo *root,
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index ebda308..733e40d 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -49,7 +49,7 @@ extern PGDLLIMPORT join_search_hook_type join_search_hook;
extern RelOptInfo *make_one_rel(PlannerInfo *root, List *joinlist);
-extern void set_dummy_rel_pathlist(RelOptInfo *rel);
+extern void set_dummy_rel_pathlist(PlannerInfo *root, RelOptInfo *rel);
extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
--
1.7.9.5
0002-Patch-to-measure-memory-used-in-CurrentMemoryContext.patchapplication/octet-stream; name=0002-Patch-to-measure-memory-used-in-CurrentMemoryContext.patchDownload
From 4f5bde7a4902e3cd2ef2a1dd4cfec2d93c695966 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 1 Mar 2017 12:12:11 +0530
Subject: [PATCH 2/3] Patch to measure memory used in CurrentMemoryContext in
standard_planner().
---
src/backend/optimizer/plan/planner.c | 5 +++++
src/backend/utils/mmgr/mcxt.c | 26 ++++++++++++++++++++++++++
src/include/utils/memutils.h | 6 ++++++
3 files changed, 37 insertions(+)
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index b74e887..410750d 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -195,6 +195,9 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
Plan *top_plan;
ListCell *lp,
*lr;
+ MemoryContextCounters mem_start;
+
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, __FUNCTION__);
/*
* Set up global state for this planner invocation. This data is needed
@@ -425,6 +428,8 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
MemoryContextResetAndDeleteChildren(glob->path_cxt);
glob->path_cxt = NULL;
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
+
return result;
}
diff --git a/src/backend/utils/mmgr/mcxt.c b/src/backend/utils/mmgr/mcxt.c
index 6ad0bb4..94b25ac 100644
--- a/src/backend/utils/mmgr/mcxt.c
+++ b/src/backend/utils/mmgr/mcxt.c
@@ -577,6 +577,32 @@ MemoryContextStatsInternal(MemoryContext context, int level,
}
}
+void
+MemoryContextFuncStatsStart(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *label)
+{
+ memset(start_counts, 0, sizeof(*start_counts));
+ MemoryContextStatsInternal(context, 0, false, 100, start_counts);
+}
+
+void
+MemoryContextFuncStatsEnd(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *label)
+{
+ MemoryContextCounters end_counts;
+ Size start_used_space = start_counts->totalspace - start_counts->freespace;
+ Size end_used_space;
+
+ memset(&end_counts, 0, sizeof(end_counts));
+ MemoryContextStatsInternal(context, 0, false, 100, &end_counts);
+ end_used_space = end_counts.totalspace - end_counts.freespace;
+
+ elog(NOTICE, "%s,%s,%zu,%zu,%ld", label, context->name,
+ start_used_space, end_used_space, end_used_space - start_used_space);
+}
+
/*
* MemoryContextCheck
* Check all chunks in the named context.
diff --git a/src/include/utils/memutils.h b/src/include/utils/memutils.h
index 1d1035e..7d605b1 100644
--- a/src/include/utils/memutils.h
+++ b/src/include/utils/memutils.h
@@ -122,6 +122,12 @@ extern MemoryContext MemoryContextCreate(NodeTag tag, Size size,
MemoryContextMethods *methods,
MemoryContext parent,
const char *name);
+extern void MemoryContextFuncStatsStart(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *func_label);
+extern void MemoryContextFuncStatsEnd(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *func_label);
/*
--
1.7.9.5
0003-GUC-zap_path-to-enable-freeing-memory-consumed-by-pa.patchapplication/octet-stream; name=0003-GUC-zap_path-to-enable-freeing-memory-consumed-by-pa.patchDownload
From 760d328696a460deb418c8fa34b80e53fa530129 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 1 Mar 2017 13:29:51 +0530
Subject: [PATCH 3/3] GUC zap_path to enable freeing memory consumed by paths.
For measuring the memory saved, add a GUC zap_path to enable/disable
freeing memory occupied by paths.
---
src/backend/optimizer/path/costsize.c | 1 +
src/backend/optimizer/plan/planner.c | 15 +++++++++------
src/backend/utils/misc/guc.c | 10 ++++++++++
src/include/optimizer/cost.h | 1 +
4 files changed, 21 insertions(+), 6 deletions(-)
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index c138f57..f4dfa00 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,7 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool zap_paths = true;
typedef struct
{
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 410750d..c7b085f 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -421,12 +421,15 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
result->stmt_location = parse->stmt_location;
result->stmt_len = parse->stmt_len;
- /*
- * We do not need paths any more, blow those away.
- * TODO: probably we should also set the pathlists to NIL.
- */
- MemoryContextResetAndDeleteChildren(glob->path_cxt);
- glob->path_cxt = NULL;
+ if (zap_paths)
+ {
+ /*
+ * We do not need paths any more, blow those away.
+ * TODO: probably we should also set the pathlists to NIL.
+ */
+ MemoryContextResetAndDeleteChildren(glob->path_cxt);
+ glob->path_cxt = NULL;
+ }
MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 2477138..630d3f7 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -912,6 +912,16 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+
+ {
+ {"zap_paths", PGC_USERSET, QUERY_TUNING_GEQO,
+ gettext_noop("Free up the memory used by paths at the end of planning."),
+ },
+ &zap_paths,
+ true,
+ NULL, NULL, NULL
+ },
+
{
/* Not for general use --- used by SET SESSION AUTHORIZATION */
{"is_superuser", PGC_INTERNAL, UNGROUPED,
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 72200fa..fc882ad 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -67,6 +67,7 @@ extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
extern int constraint_exclusion;
+extern bool zap_paths;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
--
1.7.9.5
Updated 0001 patch with some more comments. Attaching all the patches
for quick access.
On Wed, Mar 1, 2017 at 2:26 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
2. If the PartitionJoinPath emerges as the best path, we create paths
for each of the remaining child-joins. Then we collect paths with
properties same as the given PartitionJoinPath, one from each
child-join. These paths are converted into plans and a Merge/Append
plan is created combing these plans. The paths and plans for
child-join are created in a temporary memory context. The final plan
for each child-join is copied into planner's context and the temporary
memory context is reset.Robert and I discussed this in more detail. Path creation code may
allocate objects other than paths. postgres_fdw, for example,
allocates character array to hold the name of relation being
pushed-down. When the temporary context gets zapped after creating
paths for a given child-join, those other objects also gets thrown
away. Attached patch has implemented the idea that came out of the
discussion.We create a memory context for holding paths at the time of creating
PlannerGlobal and save it in PlannerGlobal. The patch introduces a new
macro makePathNode() which allocates the memory for given type of path
from this context. Every create_*_path function has been changed to
use this macro instead of makeNode(). In standard_planner(), at the
end of planning we destroy the memory context freeing all the paths
allocated. While creating a plan node, planner copies everything
required by the plan from the path, so the path is not needed any
more. So, freeing corresponding memory should not have any adverse
effects.Most of the create_*_path() functions accept root as an argument, thus
the temporary path context is available through root->glob everywhere.
An exception is create_append_path() which does not accept root as an
argument. The patch changes create_append_path() and its callers like
set_dummy_rel_pathlist(), mark_dummy_rel() to accept root as an
argument. Ideally paths are not required after creating plan, so we
should be
able to free the context right after the call to create_plan(). But we
need dummy paths while creating flat rtable in
set_plan_references()->add_rtes_to_flat_rtable(). We used to So free
the path context at the end of planning cycle. Now that we are
allocating all the paths in a different memory context, it doesn't
make sense to switch context in mark_dummy_rel().0001 patch implements the idea described above.
0002 patch adds instrumentation to measure memory consumed in
standard_planner() call.
0003 patch adds a GUC zap_paths to enable/disable destroying path context.
The last two patches are for testing only.Attached also find the SQL script and its output showing the memory
saved. For a 5 way self-join of pg_class, the total memory consumed in
standard_planner() is 760K without patch and with patch it comes down
to 713K, saving 47K memory otherwise occupied by paths. It looks like
something useful even without partition-wise joins.--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
0001-Free-up-memory-consumed-by-the-paths.patchapplication/octet-stream; name=0001-Free-up-memory-consumed-by-the-paths.patchDownload
From 02bca46338c9623735b466ccda52265fece6cafe Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 1 Mar 2017 11:07:28 +0530
Subject: [PATCH 1/3] Free up memory consumed by the paths.
Optimizer creates many paths while planning the query. Only one path
tree gets converted to the plan. Paths continue to occupy memory even
after the plan is created. For an un-PREPAREd query, it means that the
memory remains occupied till the end of the execution. Since plan node
copies the relevant information from the corresponding path, paths are
not needed after plan is created. We can free up that memory.
While creating global planner structure (PlannerGlob) we allocate a
separate memory context for creating paths. Every create_*_path()
function allocates path node in this context. The context is freed at
the end of planning cycle after creating PlannedStmt.
Ideally paths are not required after creating plan, so we should be
able to free the context right after the call to create_plan(). But we
need dummy paths while creating flat rtable in
set_plan_references()->add_rtes_to_flat_rtable(). There might be other
corner cases where we need paths. So free the path context at the end
of planning cycle.
Now that we have separate memory context to hold paths, we don't need
to switch contexts in make_dummy_rel().
---
src/backend/optimizer/path/allpaths.c | 25 ++++----
src/backend/optimizer/path/joinpath.c | 2 +-
src/backend/optimizer/path/joinrels.c | 37 ++++--------
src/backend/optimizer/plan/planner.c | 16 ++++-
src/backend/optimizer/prep/prepunion.c | 4 +-
src/backend/optimizer/util/pathnode.c | 100 ++++++++++++++++++++------------
src/include/nodes/relation.h | 2 +
src/include/optimizer/pathnode.h | 10 +++-
src/include/optimizer/paths.h | 2 +-
9 files changed, 113 insertions(+), 85 deletions(-)
diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c
index 633b5c1..e22817e 100644
--- a/src/backend/optimizer/path/allpaths.c
+++ b/src/backend/optimizer/path/allpaths.c
@@ -325,7 +325,7 @@ set_rel_size(PlannerInfo *root, RelOptInfo *rel,
* we don't have a convention for marking a rel as dummy except by
* assigning a dummy path to it.
*/
- set_dummy_rel_pathlist(rel);
+ set_dummy_rel_pathlist(root, rel);
}
else if (rte->inh)
{
@@ -769,7 +769,7 @@ set_tablesample_rel_pathlist(PlannerInfo *root, RelOptInfo *rel, RangeTblEntry *
bms_membership(root->all_baserels) != BMS_SINGLETON) &&
!(GetTsmRoutine(rte->tablesample->tsmhandler)->repeatable_across_scans))
{
- path = (Path *) create_material_path(rel, path);
+ path = (Path *) create_material_path(root, rel, path);
}
add_path(rel, path);
@@ -993,7 +993,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* Some restriction clause reduced to constant FALSE or NULL after
* substitution, so this child need not be scanned.
*/
- set_dummy_rel_pathlist(childrel);
+ set_dummy_rel_pathlist(root, childrel);
continue;
}
@@ -1003,7 +1003,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* This child need not be scanned, so we can omit it from the
* appendrel.
*/
- set_dummy_rel_pathlist(childrel);
+ set_dummy_rel_pathlist(root, childrel);
continue;
}
@@ -1153,7 +1153,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel,
* appendrel dummy. We must do this in this phase so that the rel's
* dummy-ness is visible when we generate paths for other rels.
*/
- set_dummy_rel_pathlist(rel);
+ set_dummy_rel_pathlist(root, rel);
}
pfree(parent_attrsizes);
@@ -1314,7 +1314,8 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
* if we have zero or one live subpath due to constraint exclusion.)
*/
if (subpaths_valid)
- add_path(rel, (Path *) create_append_path(rel, subpaths, NULL, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, subpaths, NULL,
+ 0));
/*
* Consider an append of partial unordered, unparameterized partial paths.
@@ -1340,7 +1341,7 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
Assert(parallel_workers > 0);
/* Generate a partial append path. */
- appendpath = create_append_path(rel, partial_subpaths, NULL,
+ appendpath = create_append_path(root, rel, partial_subpaths, NULL,
parallel_workers);
add_partial_path(rel, (Path *) appendpath);
}
@@ -1392,8 +1393,8 @@ set_append_rel_pathlist(PlannerInfo *root, RelOptInfo *rel,
}
if (subpaths_valid)
- add_path(rel, (Path *)
- create_append_path(rel, subpaths, required_outer, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, subpaths,
+ required_outer, 0));
}
}
@@ -1613,7 +1614,7 @@ accumulate_append_subpath(List *subpaths, Path *path)
* This is exported because inheritance_planner() has need for it.
*/
void
-set_dummy_rel_pathlist(RelOptInfo *rel)
+set_dummy_rel_pathlist(PlannerInfo *root, RelOptInfo *rel)
{
/* Set dummy size estimates --- we leave attr_widths[] as zeroes */
rel->rows = 0;
@@ -1623,7 +1624,7 @@ set_dummy_rel_pathlist(RelOptInfo *rel)
rel->pathlist = NIL;
rel->partial_pathlist = NIL;
- add_path(rel, (Path *) create_append_path(rel, NIL, NULL, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, NIL, NULL, 0));
/*
* We set the cheapest path immediately, to ensure that IS_DUMMY_REL()
@@ -1808,7 +1809,7 @@ set_subquery_pathlist(PlannerInfo *root, RelOptInfo *rel,
if (IS_DUMMY_REL(sub_final_rel))
{
- set_dummy_rel_pathlist(rel);
+ set_dummy_rel_pathlist(root, rel);
return;
}
diff --git a/src/backend/optimizer/path/joinpath.c b/src/backend/optimizer/path/joinpath.c
index 2897245..2a0f6d9 100644
--- a/src/backend/optimizer/path/joinpath.c
+++ b/src/backend/optimizer/path/joinpath.c
@@ -1124,7 +1124,7 @@ match_unsorted_outer(PlannerInfo *root,
if (enable_material && inner_cheapest_total != NULL &&
!ExecMaterializesOutput(inner_cheapest_total->pathtype))
matpath = (Path *)
- create_material_path(innerrel, inner_cheapest_total);
+ create_material_path(root, innerrel, inner_cheapest_total);
}
foreach(lc1, outerrel->pathlist)
diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c
index 0d00683..f0c8b62 100644
--- a/src/backend/optimizer/path/joinrels.c
+++ b/src/backend/optimizer/path/joinrels.c
@@ -29,7 +29,7 @@ static void make_rels_by_clauseless_joins(PlannerInfo *root,
static bool has_join_restriction(PlannerInfo *root, RelOptInfo *rel);
static bool has_legal_joinclause(PlannerInfo *root, RelOptInfo *rel);
static bool is_dummy_rel(RelOptInfo *rel);
-static void mark_dummy_rel(RelOptInfo *rel);
+static void mark_dummy_rel(PlannerInfo *root, RelOptInfo *rel);
static bool restriction_is_constant_false(List *restrictlist,
bool only_pushed_down);
@@ -748,7 +748,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) || is_dummy_rel(rel2) ||
restriction_is_constant_false(restrictlist, false))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -762,12 +762,12 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) ||
restriction_is_constant_false(restrictlist, true))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
if (restriction_is_constant_false(restrictlist, false) &&
bms_is_subset(rel2->relids, sjinfo->syn_righthand))
- mark_dummy_rel(rel2);
+ mark_dummy_rel(root, rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_LEFT, sjinfo,
restrictlist);
@@ -779,7 +779,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if ((is_dummy_rel(rel1) && is_dummy_rel(rel2)) ||
restriction_is_constant_false(restrictlist, true))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -815,7 +815,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) || is_dummy_rel(rel2) ||
restriction_is_constant_false(restrictlist, false))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -838,7 +838,7 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) || is_dummy_rel(rel2) ||
restriction_is_constant_false(restrictlist, false))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
add_paths_to_joinrel(root, joinrel, rel1, rel2,
@@ -853,12 +853,12 @@ make_join_rel(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2)
if (is_dummy_rel(rel1) ||
restriction_is_constant_false(restrictlist, true))
{
- mark_dummy_rel(joinrel);
+ mark_dummy_rel(root, joinrel);
break;
}
if (restriction_is_constant_false(restrictlist, false) &&
bms_is_subset(rel2->relids, sjinfo->syn_righthand))
- mark_dummy_rel(rel2);
+ mark_dummy_rel(root, rel2);
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
@@ -1168,27 +1168,14 @@ is_dummy_rel(RelOptInfo *rel)
* During GEQO planning, this can get invoked more than once on the same
* baserel struct, so it's worth checking to see if the rel is already marked
* dummy.
- *
- * Also, when called during GEQO join planning, we are in a short-lived
- * memory context. We must make sure that the dummy path attached to a
- * baserel survives the GEQO cycle, else the baserel is trashed for future
- * GEQO cycles. On the other hand, when we are marking a joinrel during GEQO,
- * we don't want the dummy path to clutter the main planning context. Upshot
- * is that the best solution is to explicitly make the dummy path in the same
- * context the given RelOptInfo is in.
*/
static void
-mark_dummy_rel(RelOptInfo *rel)
+mark_dummy_rel(PlannerInfo *root, RelOptInfo *rel)
{
- MemoryContext oldcontext;
-
/* Already marked? */
if (is_dummy_rel(rel))
return;
- /* No, so choose correct context to make the dummy path in */
- oldcontext = MemoryContextSwitchTo(GetMemoryChunkContext(rel));
-
/* Set dummy size estimate */
rel->rows = 0;
@@ -1197,12 +1184,10 @@ mark_dummy_rel(RelOptInfo *rel)
rel->partial_pathlist = NIL;
/* Set up the dummy path */
- add_path(rel, (Path *) create_append_path(rel, NIL, NULL, 0));
+ add_path(rel, (Path *) create_append_path(root, rel, NIL, NULL, 0));
/* Set or update cheapest_total_path and related fields */
set_cheapest(rel);
-
- MemoryContextSwitchTo(oldcontext);
}
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index ca0ae78..b74e887 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -54,6 +54,7 @@
#include "utils/rel.h"
#include "utils/selfuncs.h"
#include "utils/lsyscache.h"
+#include "utils/memutils.h"
#include "utils/syscache.h"
@@ -218,6 +219,9 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
glob->lastPlanNodeId = 0;
glob->transientPlan = false;
glob->dependsOnRole = false;
+ glob->path_cxt = AllocSetContextCreate(CurrentMemoryContext,
+ "Path creation temporary context",
+ ALLOCSET_DEFAULT_SIZES);
/*
* Assess whether it's feasible to use parallel mode for this query. We
@@ -414,6 +418,13 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
result->stmt_location = parse->stmt_location;
result->stmt_len = parse->stmt_len;
+ /*
+ * We do not need paths any more, blow those away.
+ * TODO: probably we should also set the pathlists to NIL.
+ */
+ MemoryContextResetAndDeleteChildren(glob->path_cxt);
+ glob->path_cxt = NULL;
+
return result;
}
@@ -1302,7 +1313,7 @@ inheritance_planner(PlannerInfo *root)
*/
if (subpaths == NIL)
{
- set_dummy_rel_pathlist(final_rel);
+ set_dummy_rel_pathlist(root, final_rel);
return;
}
@@ -3334,7 +3345,7 @@ create_grouping_paths(PlannerInfo *root,
paths = lappend(paths, path);
}
path = (Path *)
- create_append_path(grouped_rel,
+ create_append_path(root, grouped_rel,
paths,
NULL,
0);
@@ -5261,6 +5272,7 @@ plan_cluster_use_sort(Oid tableOid, Oid indexOid)
query->commandType = CMD_SELECT;
glob = makeNode(PlannerGlobal);
+ glob->path_cxt = CurrentMemoryContext;
root = makeNode(PlannerInfo);
root->parse = query;
diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c
index 1389db1..492f8df 100644
--- a/src/backend/optimizer/prep/prepunion.c
+++ b/src/backend/optimizer/prep/prepunion.c
@@ -566,7 +566,7 @@ generate_union_path(SetOperationStmt *op, PlannerInfo *root,
/*
* Append the child results together.
*/
- path = (Path *) create_append_path(result_rel, pathlist, NULL, 0);
+ path = (Path *) create_append_path(root, result_rel, pathlist, NULL, 0);
/* We have to manually jam the right tlist into the path; ick */
path->pathtarget = create_pathtarget(root, tlist);
@@ -678,7 +678,7 @@ generate_nonunion_path(SetOperationStmt *op, PlannerInfo *root,
/*
* Append the child results together.
*/
- path = (Path *) create_append_path(result_rel, pathlist, NULL, 0);
+ path = (Path *) create_append_path(root, result_rel, pathlist, NULL, 0);
/* We have to manually jam the right tlist into the path; ick */
path->pathtarget = create_pathtarget(root, tlist);
diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c
index 3248296..3f1184c 100644
--- a/src/backend/optimizer/util/pathnode.c
+++ b/src/backend/optimizer/util/pathnode.c
@@ -930,6 +930,27 @@ add_partial_path_precheck(RelOptInfo *parent_rel, Cost total_cost,
*****************************************************************************/
/*
+ * The memory consumed by paths remains occupied after the plan is created.
+ * For an un-PREPAREd query, it means that the paths continue to occupy the
+ * memory till the end of the execution. Since plan node copies the relevant
+ * information from the corresponding path, paths are not needed after plan is
+ * created. Following macro creates specified Path node in a temporary memory
+ * context allocated while creating PlannerGlobal. This memory context is
+ * reset at the end of planning to free up any memory consumed by paths.
+ */
+#define makePathNode(root, _type_) ((_type_ *) newPath((root), sizeof(_type_),T_##_type_))
+static Path *
+newPath(PlannerInfo *root, size_t size, NodeTag tag)
+{
+ Path *result;
+
+ Assert(sizeof(Path) <= size);
+ result = MemoryContextAllocZero(root->glob->path_cxt, size);
+ result->type = tag;
+ return result;
+}
+
+/*
* create_seqscan_path
* Creates a path corresponding to a sequential scan, returning the
* pathnode.
@@ -938,7 +959,7 @@ Path *
create_seqscan_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer, int parallel_workers)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_SeqScan;
pathnode->parent = rel;
@@ -962,7 +983,7 @@ create_seqscan_path(PlannerInfo *root, RelOptInfo *rel,
Path *
create_samplescan_path(PlannerInfo *root, RelOptInfo *rel, Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_SampleScan;
pathnode->parent = rel;
@@ -1018,7 +1039,7 @@ create_index_path(PlannerInfo *root,
double loop_count,
bool partial_path)
{
- IndexPath *pathnode = makeNode(IndexPath);
+ IndexPath *pathnode = makePathNode(root, IndexPath);
RelOptInfo *rel = index->rel;
List *indexquals,
*indexqualcols;
@@ -1070,7 +1091,7 @@ create_bitmap_heap_path(PlannerInfo *root,
Relids required_outer,
double loop_count)
{
- BitmapHeapPath *pathnode = makeNode(BitmapHeapPath);
+ BitmapHeapPath *pathnode = makePathNode(root, BitmapHeapPath);
pathnode->path.pathtype = T_BitmapHeapScan;
pathnode->path.parent = rel;
@@ -1100,7 +1121,7 @@ create_bitmap_and_path(PlannerInfo *root,
RelOptInfo *rel,
List *bitmapquals)
{
- BitmapAndPath *pathnode = makeNode(BitmapAndPath);
+ BitmapAndPath *pathnode = makePathNode(root, BitmapAndPath);
pathnode->path.pathtype = T_BitmapAnd;
pathnode->path.parent = rel;
@@ -1136,7 +1157,7 @@ create_bitmap_or_path(PlannerInfo *root,
RelOptInfo *rel,
List *bitmapquals)
{
- BitmapOrPath *pathnode = makeNode(BitmapOrPath);
+ BitmapOrPath *pathnode = makePathNode(root, BitmapOrPath);
pathnode->path.pathtype = T_BitmapOr;
pathnode->path.parent = rel;
@@ -1171,7 +1192,7 @@ TidPath *
create_tidscan_path(PlannerInfo *root, RelOptInfo *rel, List *tidquals,
Relids required_outer)
{
- TidPath *pathnode = makeNode(TidPath);
+ TidPath *pathnode = makePathNode(root, TidPath);
pathnode->path.pathtype = T_TidScan;
pathnode->path.parent = rel;
@@ -1199,10 +1220,13 @@ create_tidscan_path(PlannerInfo *root, RelOptInfo *rel, List *tidquals,
* Note that we must handle subpaths = NIL, representing a dummy access path.
*/
AppendPath *
-create_append_path(RelOptInfo *rel, List *subpaths, Relids required_outer,
+create_append_path(PlannerInfo *root,
+ RelOptInfo *rel,
+ List *subpaths,
+ Relids required_outer,
int parallel_workers)
{
- AppendPath *pathnode = makeNode(AppendPath);
+ AppendPath *pathnode = makePathNode(root, AppendPath);
ListCell *l;
pathnode->path.pathtype = T_Append;
@@ -1259,7 +1283,7 @@ create_merge_append_path(PlannerInfo *root,
List *pathkeys,
Relids required_outer)
{
- MergeAppendPath *pathnode = makeNode(MergeAppendPath);
+ MergeAppendPath *pathnode = makePathNode(root, MergeAppendPath);
Cost input_startup_cost;
Cost input_total_cost;
ListCell *l;
@@ -1346,7 +1370,7 @@ ResultPath *
create_result_path(PlannerInfo *root, RelOptInfo *rel,
PathTarget *target, List *resconstantqual)
{
- ResultPath *pathnode = makeNode(ResultPath);
+ ResultPath *pathnode = makePathNode(root, ResultPath);
pathnode->path.pathtype = T_Result;
pathnode->path.parent = rel;
@@ -1382,9 +1406,9 @@ create_result_path(PlannerInfo *root, RelOptInfo *rel,
* pathnode.
*/
MaterialPath *
-create_material_path(RelOptInfo *rel, Path *subpath)
+create_material_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath)
{
- MaterialPath *pathnode = makeNode(MaterialPath);
+ MaterialPath *pathnode = makePathNode(root, MaterialPath);
Assert(subpath->parent == rel);
@@ -1451,7 +1475,7 @@ create_unique_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
*/
oldcontext = MemoryContextSwitchTo(root->planner_cxt);
- pathnode = makeNode(UniquePath);
+ pathnode = makePathNode(root, UniquePath);
pathnode->path.pathtype = T_Unique;
pathnode->path.parent = rel;
@@ -1667,7 +1691,7 @@ GatherPath *
create_gather_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
PathTarget *target, Relids required_outer, double *rows)
{
- GatherPath *pathnode = makeNode(GatherPath);
+ GatherPath *pathnode = makePathNode(root, GatherPath);
Assert(subpath->parallel_safe);
@@ -1705,7 +1729,7 @@ SubqueryScanPath *
create_subqueryscan_path(PlannerInfo *root, RelOptInfo *rel, Path *subpath,
List *pathkeys, Relids required_outer)
{
- SubqueryScanPath *pathnode = makeNode(SubqueryScanPath);
+ SubqueryScanPath *pathnode = makePathNode(root, SubqueryScanPath);
pathnode->path.pathtype = T_SubqueryScan;
pathnode->path.parent = rel;
@@ -1733,7 +1757,7 @@ Path *
create_functionscan_path(PlannerInfo *root, RelOptInfo *rel,
List *pathkeys, Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_FunctionScan;
pathnode->parent = rel;
@@ -1759,7 +1783,7 @@ Path *
create_valuesscan_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_ValuesScan;
pathnode->parent = rel;
@@ -1784,7 +1808,7 @@ create_valuesscan_path(PlannerInfo *root, RelOptInfo *rel,
Path *
create_ctescan_path(PlannerInfo *root, RelOptInfo *rel, Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_CteScan;
pathnode->parent = rel;
@@ -1810,7 +1834,7 @@ Path *
create_worktablescan_path(PlannerInfo *root, RelOptInfo *rel,
Relids required_outer)
{
- Path *pathnode = makeNode(Path);
+ Path *pathnode = makePathNode(root, Path);
pathnode->pathtype = T_WorkTableScan;
pathnode->parent = rel;
@@ -1849,7 +1873,7 @@ create_foreignscan_path(PlannerInfo *root, RelOptInfo *rel,
Path *fdw_outerpath,
List *fdw_private)
{
- ForeignPath *pathnode = makeNode(ForeignPath);
+ ForeignPath *pathnode = makePathNode(root, ForeignPath);
pathnode->path.pathtype = T_ForeignScan;
pathnode->path.parent = rel;
@@ -1955,7 +1979,7 @@ create_nestloop_path(PlannerInfo *root,
List *pathkeys,
Relids required_outer)
{
- NestPath *pathnode = makeNode(NestPath);
+ NestPath *pathnode = makePathNode(root, NestPath);
Relids inner_req_outer = PATH_REQ_OUTER(inner_path);
/*
@@ -2045,7 +2069,7 @@ create_mergejoin_path(PlannerInfo *root,
List *outersortkeys,
List *innersortkeys)
{
- MergePath *pathnode = makeNode(MergePath);
+ MergePath *pathnode = makePathNode(root, MergePath);
pathnode->jpath.path.pathtype = T_MergeJoin;
pathnode->jpath.path.parent = joinrel;
@@ -2107,7 +2131,7 @@ create_hashjoin_path(PlannerInfo *root,
Relids required_outer,
List *hashclauses)
{
- HashPath *pathnode = makeNode(HashPath);
+ HashPath *pathnode = makePathNode(root, HashPath);
pathnode->jpath.path.pathtype = T_HashJoin;
pathnode->jpath.path.parent = joinrel;
@@ -2164,7 +2188,7 @@ create_projection_path(PlannerInfo *root,
Path *subpath,
PathTarget *target)
{
- ProjectionPath *pathnode = makeNode(ProjectionPath);
+ ProjectionPath *pathnode = makePathNode(root, ProjectionPath);
PathTarget *oldtarget = subpath->pathtarget;
pathnode->path.pathtype = T_Result;
@@ -2331,7 +2355,7 @@ create_set_projection_path(PlannerInfo *root,
Path *subpath,
PathTarget *target)
{
- ProjectSetPath *pathnode = makeNode(ProjectSetPath);
+ ProjectSetPath *pathnode = makePathNode(root, ProjectSetPath);
double tlist_rows;
ListCell *lc;
@@ -2399,7 +2423,7 @@ create_sort_path(PlannerInfo *root,
List *pathkeys,
double limit_tuples)
{
- SortPath *pathnode = makeNode(SortPath);
+ SortPath *pathnode = makePathNode(root, SortPath);
pathnode->path.pathtype = T_Sort;
pathnode->path.parent = rel;
@@ -2445,7 +2469,7 @@ create_group_path(PlannerInfo *root,
List *qual,
double numGroups)
{
- GroupPath *pathnode = makeNode(GroupPath);
+ GroupPath *pathnode = makePathNode(root, GroupPath);
pathnode->path.pathtype = T_Group;
pathnode->path.parent = rel;
@@ -2501,7 +2525,7 @@ create_upper_unique_path(PlannerInfo *root,
int numCols,
double numGroups)
{
- UpperUniquePath *pathnode = makeNode(UpperUniquePath);
+ UpperUniquePath *pathnode = makePathNode(root, UpperUniquePath);
pathnode->path.pathtype = T_Unique;
pathnode->path.parent = rel;
@@ -2558,7 +2582,7 @@ create_agg_path(PlannerInfo *root,
const AggClauseCosts *aggcosts,
double numGroups)
{
- AggPath *pathnode = makeNode(AggPath);
+ AggPath *pathnode = makePathNode(root, AggPath);
pathnode->path.pathtype = T_Agg;
pathnode->path.parent = rel;
@@ -2623,7 +2647,7 @@ create_groupingsets_path(PlannerInfo *root,
const AggClauseCosts *agg_costs,
double numGroups)
{
- GroupingSetsPath *pathnode = makeNode(GroupingSetsPath);
+ GroupingSetsPath *pathnode = makePathNode(root, GroupingSetsPath);
int numGroupCols;
/* The topmost generated Plan node will be an Agg */
@@ -2736,7 +2760,7 @@ create_minmaxagg_path(PlannerInfo *root,
List *mmaggregates,
List *quals)
{
- MinMaxAggPath *pathnode = makeNode(MinMaxAggPath);
+ MinMaxAggPath *pathnode = makePathNode(root, MinMaxAggPath);
Cost initplan_cost;
ListCell *lc;
@@ -2797,7 +2821,7 @@ create_windowagg_path(PlannerInfo *root,
WindowClause *winclause,
List *winpathkeys)
{
- WindowAggPath *pathnode = makeNode(WindowAggPath);
+ WindowAggPath *pathnode = makePathNode(root, WindowAggPath);
pathnode->path.pathtype = T_WindowAgg;
pathnode->path.parent = rel;
@@ -2864,7 +2888,7 @@ create_setop_path(PlannerInfo *root,
double numGroups,
double outputRows)
{
- SetOpPath *pathnode = makeNode(SetOpPath);
+ SetOpPath *pathnode = makePathNode(root, SetOpPath);
pathnode->path.pathtype = T_SetOp;
pathnode->path.parent = rel;
@@ -2924,7 +2948,7 @@ create_recursiveunion_path(PlannerInfo *root,
int wtParam,
double numGroups)
{
- RecursiveUnionPath *pathnode = makeNode(RecursiveUnionPath);
+ RecursiveUnionPath *pathnode = makePathNode(root, RecursiveUnionPath);
pathnode->path.pathtype = T_RecursiveUnion;
pathnode->path.parent = rel;
@@ -2963,7 +2987,7 @@ LockRowsPath *
create_lockrows_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath, List *rowMarks, int epqParam)
{
- LockRowsPath *pathnode = makeNode(LockRowsPath);
+ LockRowsPath *pathnode = makePathNode(root, LockRowsPath);
pathnode->path.pathtype = T_LockRows;
pathnode->path.parent = rel;
@@ -3025,7 +3049,7 @@ create_modifytable_path(PlannerInfo *root, RelOptInfo *rel,
List *rowMarks, OnConflictExpr *onconflict,
int epqParam)
{
- ModifyTablePath *pathnode = makeNode(ModifyTablePath);
+ ModifyTablePath *pathnode = makePathNode(root, ModifyTablePath);
double total_size;
ListCell *lc;
@@ -3120,7 +3144,7 @@ create_limit_path(PlannerInfo *root, RelOptInfo *rel,
Node *limitOffset, Node *limitCount,
int64 offset_est, int64 count_est)
{
- LimitPath *pathnode = makeNode(LimitPath);
+ LimitPath *pathnode = makePathNode(root, LimitPath);
pathnode->path.pathtype = T_Limit;
pathnode->path.parent = rel;
diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h
index f7ac6f6..aa2e9b3 100644
--- a/src/include/nodes/relation.h
+++ b/src/include/nodes/relation.h
@@ -128,6 +128,8 @@ typedef struct PlannerGlobal
bool parallelModeNeeded; /* parallel mode actually required? */
char maxParallelHazard; /* worst PROPARALLEL hazard level */
+
+ MemoryContext path_cxt; /* Temporary context for holding paths. */
} PlannerGlobal;
/* macro for fetching the Plan associated with a SubPlan node */
diff --git a/src/include/optimizer/pathnode.h b/src/include/optimizer/pathnode.h
index 53cad24..18591df 100644
--- a/src/include/optimizer/pathnode.h
+++ b/src/include/optimizer/pathnode.h
@@ -62,8 +62,11 @@ extern BitmapOrPath *create_bitmap_or_path(PlannerInfo *root,
List *bitmapquals);
extern TidPath *create_tidscan_path(PlannerInfo *root, RelOptInfo *rel,
List *tidquals, Relids required_outer);
-extern AppendPath *create_append_path(RelOptInfo *rel, List *subpaths,
- Relids required_outer, int parallel_workers);
+extern AppendPath *create_append_path(PlannerInfo *root,
+ RelOptInfo *rel,
+ List *subpaths,
+ Relids required_outer,
+ int parallel_workers);
extern MergeAppendPath *create_merge_append_path(PlannerInfo *root,
RelOptInfo *rel,
List *subpaths,
@@ -71,7 +74,8 @@ extern MergeAppendPath *create_merge_append_path(PlannerInfo *root,
Relids required_outer);
extern ResultPath *create_result_path(PlannerInfo *root, RelOptInfo *rel,
PathTarget *target, List *resconstantqual);
-extern MaterialPath *create_material_path(RelOptInfo *rel, Path *subpath);
+extern MaterialPath *create_material_path(PlannerInfo *root, RelOptInfo *rel,
+ Path *subpath);
extern UniquePath *create_unique_path(PlannerInfo *root, RelOptInfo *rel,
Path *subpath, SpecialJoinInfo *sjinfo);
extern GatherPath *create_gather_path(PlannerInfo *root,
diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h
index ebda308..733e40d 100644
--- a/src/include/optimizer/paths.h
+++ b/src/include/optimizer/paths.h
@@ -49,7 +49,7 @@ extern PGDLLIMPORT join_search_hook_type join_search_hook;
extern RelOptInfo *make_one_rel(PlannerInfo *root, List *joinlist);
-extern void set_dummy_rel_pathlist(RelOptInfo *rel);
+extern void set_dummy_rel_pathlist(PlannerInfo *root, RelOptInfo *rel);
extern RelOptInfo *standard_join_search(PlannerInfo *root, int levels_needed,
List *initial_rels);
--
1.7.9.5
0002-Patch-to-measure-memory-used-in-CurrentMemoryContext.patchapplication/octet-stream; name=0002-Patch-to-measure-memory-used-in-CurrentMemoryContext.patchDownload
From f01a67fe92eb5046d208cfa11578fe753562d8e0 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 1 Mar 2017 12:12:11 +0530
Subject: [PATCH 2/3] Patch to measure memory used in CurrentMemoryContext in
standard_planner().
---
src/backend/optimizer/plan/planner.c | 5 +++++
src/backend/utils/mmgr/mcxt.c | 26 ++++++++++++++++++++++++++
src/include/utils/memutils.h | 6 ++++++
3 files changed, 37 insertions(+)
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index b74e887..410750d 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -195,6 +195,9 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
Plan *top_plan;
ListCell *lp,
*lr;
+ MemoryContextCounters mem_start;
+
+ MemoryContextFuncStatsStart(CurrentMemoryContext, &mem_start, __FUNCTION__);
/*
* Set up global state for this planner invocation. This data is needed
@@ -425,6 +428,8 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
MemoryContextResetAndDeleteChildren(glob->path_cxt);
glob->path_cxt = NULL;
+ MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
+
return result;
}
diff --git a/src/backend/utils/mmgr/mcxt.c b/src/backend/utils/mmgr/mcxt.c
index 6ad0bb4..94b25ac 100644
--- a/src/backend/utils/mmgr/mcxt.c
+++ b/src/backend/utils/mmgr/mcxt.c
@@ -577,6 +577,32 @@ MemoryContextStatsInternal(MemoryContext context, int level,
}
}
+void
+MemoryContextFuncStatsStart(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *label)
+{
+ memset(start_counts, 0, sizeof(*start_counts));
+ MemoryContextStatsInternal(context, 0, false, 100, start_counts);
+}
+
+void
+MemoryContextFuncStatsEnd(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *label)
+{
+ MemoryContextCounters end_counts;
+ Size start_used_space = start_counts->totalspace - start_counts->freespace;
+ Size end_used_space;
+
+ memset(&end_counts, 0, sizeof(end_counts));
+ MemoryContextStatsInternal(context, 0, false, 100, &end_counts);
+ end_used_space = end_counts.totalspace - end_counts.freespace;
+
+ elog(NOTICE, "%s,%s,%zu,%zu,%ld", label, context->name,
+ start_used_space, end_used_space, end_used_space - start_used_space);
+}
+
/*
* MemoryContextCheck
* Check all chunks in the named context.
diff --git a/src/include/utils/memutils.h b/src/include/utils/memutils.h
index 1d1035e..7d605b1 100644
--- a/src/include/utils/memutils.h
+++ b/src/include/utils/memutils.h
@@ -122,6 +122,12 @@ extern MemoryContext MemoryContextCreate(NodeTag tag, Size size,
MemoryContextMethods *methods,
MemoryContext parent,
const char *name);
+extern void MemoryContextFuncStatsStart(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *func_label);
+extern void MemoryContextFuncStatsEnd(MemoryContext context,
+ MemoryContextCounters *start_counts,
+ const char *func_label);
/*
--
1.7.9.5
0003-GUC-zap_path-to-enable-freeing-memory-consumed-by-pa.patchapplication/octet-stream; name=0003-GUC-zap_path-to-enable-freeing-memory-consumed-by-pa.patchDownload
From 9c863c57c585303f2ba7b5ce4d892c723210b098 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com>
Date: Wed, 1 Mar 2017 13:29:51 +0530
Subject: [PATCH 3/3] GUC zap_path to enable freeing memory consumed by paths.
For measuring the memory saved, add a GUC zap_path to enable/disable
freeing memory occupied by paths.
---
src/backend/optimizer/path/costsize.c | 1 +
src/backend/optimizer/plan/planner.c | 15 +++++++++------
src/backend/utils/misc/guc.c | 10 ++++++++++
src/include/optimizer/cost.h | 1 +
4 files changed, 21 insertions(+), 6 deletions(-)
diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c
index c138f57..f4dfa00 100644
--- a/src/backend/optimizer/path/costsize.c
+++ b/src/backend/optimizer/path/costsize.c
@@ -126,6 +126,7 @@ bool enable_nestloop = true;
bool enable_material = true;
bool enable_mergejoin = true;
bool enable_hashjoin = true;
+bool zap_paths = true;
typedef struct
{
diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c
index 410750d..c7b085f 100644
--- a/src/backend/optimizer/plan/planner.c
+++ b/src/backend/optimizer/plan/planner.c
@@ -421,12 +421,15 @@ standard_planner(Query *parse, int cursorOptions, ParamListInfo boundParams)
result->stmt_location = parse->stmt_location;
result->stmt_len = parse->stmt_len;
- /*
- * We do not need paths any more, blow those away.
- * TODO: probably we should also set the pathlists to NIL.
- */
- MemoryContextResetAndDeleteChildren(glob->path_cxt);
- glob->path_cxt = NULL;
+ if (zap_paths)
+ {
+ /*
+ * We do not need paths any more, blow those away.
+ * TODO: probably we should also set the pathlists to NIL.
+ */
+ MemoryContextResetAndDeleteChildren(glob->path_cxt);
+ glob->path_cxt = NULL;
+ }
MemoryContextFuncStatsEnd(CurrentMemoryContext, &mem_start, __FUNCTION__);
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 2477138..630d3f7 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -912,6 +912,16 @@ static struct config_bool ConfigureNamesBool[] =
true,
NULL, NULL, NULL
},
+
+ {
+ {"zap_paths", PGC_USERSET, QUERY_TUNING_GEQO,
+ gettext_noop("Free up the memory used by paths at the end of planning."),
+ },
+ &zap_paths,
+ true,
+ NULL, NULL, NULL
+ },
+
{
/* Not for general use --- used by SET SESSION AUTHORIZATION */
{"is_superuser", PGC_INTERNAL, UNGROUPED,
diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h
index 72200fa..fc882ad 100644
--- a/src/include/optimizer/cost.h
+++ b/src/include/optimizer/cost.h
@@ -67,6 +67,7 @@ extern bool enable_material;
extern bool enable_mergejoin;
extern bool enable_hashjoin;
extern int constraint_exclusion;
+extern bool zap_paths;
extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,
--
1.7.9.5
On Wed, Mar 1, 2017 at 3:56 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:
2. If the PartitionJoinPath emerges as the best path, we create paths
for each of the remaining child-joins. Then we collect paths with
properties same as the given PartitionJoinPath, one from each
child-join. These paths are converted into plans and a Merge/Append
plan is created combing these plans. The paths and plans for
child-join are created in a temporary memory context. The final plan
for each child-join is copied into planner's context and the temporary
memory context is reset.Robert and I discussed this in more detail. Path creation code may
allocate objects other than paths. postgres_fdw, for example,
allocates character array to hold the name of relation being
pushed-down. When the temporary context gets zapped after creating
paths for a given child-join, those other objects also gets thrown
away. Attached patch has implemented the idea that came out of the
discussion.We create a memory context for holding paths at the time of creating
PlannerGlobal and save it in PlannerGlobal. The patch introduces a new
macro makePathNode() which allocates the memory for given type of path
from this context. Every create_*_path function has been changed to
use this macro instead of makeNode(). In standard_planner(), at the
end of planning we destroy the memory context freeing all the paths
allocated. While creating a plan node, planner copies everything
required by the plan from the path, so the path is not needed any
more. So, freeing corresponding memory should not have any adverse
effects.Most of the create_*_path() functions accept root as an argument, thus
the temporary path context is available through root->glob everywhere.
An exception is create_append_path() which does not accept root as an
argument. The patch changes create_append_path() and its callers like
set_dummy_rel_pathlist(), mark_dummy_rel() to accept root as an
argument. Ideally paths are not required after creating plan, so we
should be
able to free the context right after the call to create_plan(). But we
need dummy paths while creating flat rtable in
set_plan_references()->add_rtes_to_flat_rtable(). We used to So free
the path context at the end of planning cycle. Now that we are
allocating all the paths in a different memory context, it doesn't
make sense to switch context in mark_dummy_rel().0001 patch implements the idea described above.
0002 patch adds instrumentation to measure memory consumed in
standard_planner() call.
0003 patch adds a GUC zap_paths to enable/disable destroying path context.
The last two patches are for testing only.Attached also find the SQL script and its output showing the memory
saved. For a 5 way self-join of pg_class, the total memory consumed in
standard_planner() is 760K without patch and with patch it comes down
to 713K, saving 47K memory otherwise occupied by paths. It looks like
something useful even without partition-wise joins.
Of course, that's not a lot, but the savings will be a lot better for
partition-wise joins. Do you have a set of patches for that feature
that apply on top of 0001?
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
PFA the zip containing all the patches rebased on
56018bf26eec1a0b4bf20303c98065a8eb1b0c5d and contain the patch to free
memory consumed by paths using a separate path context.
There are some more changes wrt earlier set of patches
1. Since we don't need a separate context for planning for each
child_join, changed code in create_partition_join_plan() to not do
that. The function collects all child_join paths into merge/append
path and calls create_plan_recurse() on that path instead of
converting each child_join path to plan one at a time.
2. Changed optimizer/README and some comments referring to temporary
memory context, since we do not use that anymore.
3. reparameterize_path_by_child() is fixed to translate the merge and
hash clause in Hash/Merge path.
On Thu, Mar 9, 2017 at 6:44 AM, Robert Haas <robertmhaas@gmail.com> wrote:
On Wed, Mar 1, 2017 at 3:56 AM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:2. If the PartitionJoinPath emerges as the best path, we create paths
for each of the remaining child-joins. Then we collect paths with
properties same as the given PartitionJoinPath, one from each
child-join. These paths are converted into plans and a Merge/Append
plan is created combing these plans. The paths and plans for
child-join are created in a temporary memory context. The final plan
for each child-join is copied into planner's context and the temporary
memory context is reset.Robert and I discussed this in more detail. Path creation code may
allocate objects other than paths. postgres_fdw, for example,
allocates character array to hold the name of relation being
pushed-down. When the temporary context gets zapped after creating
paths for a given child-join, those other objects also gets thrown
away. Attached patch has implemented the idea that came out of the
discussion.We create a memory context for holding paths at the time of creating
PlannerGlobal and save it in PlannerGlobal. The patch introduces a new
macro makePathNode() which allocates the memory for given type of path
from this context. Every create_*_path function has been changed to
use this macro instead of makeNode(). In standard_planner(), at the
end of planning we destroy the memory context freeing all the paths
allocated. While creating a plan node, planner copies everything
required by the plan from the path, so the path is not needed any
more. So, freeing corresponding memory should not have any adverse
effects.Most of the create_*_path() functions accept root as an argument, thus
the temporary path context is available through root->glob everywhere.
An exception is create_append_path() which does not accept root as an
argument. The patch changes create_append_path() and its callers like
set_dummy_rel_pathlist(), mark_dummy_rel() to accept root as an
argument. Ideally paths are not required after creating plan, so we
should be
able to free the context right after the call to create_plan(). But we
need dummy paths while creating flat rtable in
set_plan_references()->add_rtes_to_flat_rtable(). We used to So free
the path context at the end of planning cycle. Now that we are
allocating all the paths in a different memory context, it doesn't
make sense to switch context in mark_dummy_rel().0001 patch implements the idea described above.
0002 patch adds instrumentation to measure memory consumed in
standard_planner() call.
0003 patch adds a GUC zap_paths to enable/disable destroying path context.
The last two patches are for testing only.Attached also find the SQL script and its output showing the memory
saved. For a 5 way self-join of pg_class, the total memory consumed in
standard_planner() is 760K without patch and with patch it comes down
to 713K, saving 47K memory otherwise occupied by paths. It looks like
something useful even without partition-wise joins.Of course, that's not a lot, but the savings will be a lot better for
partition-wise joins. Do you have a set of patches for that feature
that apply on top of 0001?--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_dp_join_patches_v2.zipapplication/zip; name=pg_dp_join_patches_v2.zipDownload
PK
��jJ pg_dp_join_patches_v2/UX ���X���X� PK ��jJ E pg_dp_join_patches_v2/0001-Free-up-memory-consumed-by-the-paths.patchUX ���X���X� �]{s����[����D�H� �v��V��NI�W��uI�P 0�.��������� )�&W�-J@wc�7=�===����s<�����g}(��p8���j9�RN��hi��n�V������
m&��g�O����y
b���pG~���[34���%��'�E2�N(����7/;��H>��'���4����3}�l����d4�����=}z{��j'��o�&���b#7~� ,������ADk)���p��\m#g��]�
$</�{���~��@����xw��S,�������{,����d�c>� ��D>?��=���������o�������+ eN��d�k?p)�������^�����p"�az!����Q"�1�Nr�A���t���_��_�G�M�q<K=��m��|�
�*���lz�p��lLd+T
�k�A �������S����x~$<)mh �o�oA���x�����4D���\i�<" +�����@���|�
t�����<@��Pn� �T!�_"}�$�>�s��6�������*�,�t"5$z
@�6;a"v n ~\��A��N�T������m���7�&����a*�@�;A�j�����G������c.]�:9��/p����4�2QI��v����vp �o6� �>|���=�� ��$�\�@�~����K��
�"��r�����j�R
��&8��J|"R@��-j�nr=��I��SQ�������Y�@������
��]������������J�Nl�O� ���.t����;"���i}�&����9A�'