• Home
  • History
  • Annotate
Name Date Size #Lines LOC

..03-May-2022-

geqo/H08-Nov-2021-2,5941,200

path/H03-May-2022-20,24510,463

plan/H08-Nov-2021-21,00511,634

prep/H08-Nov-2021-6,8753,840

util/H08-Nov-2021-17,2189,465

MakefileH A D08-Nov-2021249 145

READMEH A D08-Nov-202150.7 KiB977837

README

1src/backend/optimizer/README
2
3Optimizer
4=========
5
6These directories take the Query structure returned by the parser, and
7generate a plan used by the executor.  The /plan directory generates the
8actual output plan, the /path code generates all possible ways to join the
9tables, and /prep handles various preprocessing steps for special cases.
10/util is utility stuff.  /geqo is the separate "genetic optimization" planner
11--- it does a semi-random search through the join tree space, rather than
12exhaustively considering all possible join trees.  (But each join considered
13by /geqo is given to /path to create paths for, so we consider all possible
14implementation paths for each specific join pair even in GEQO mode.)
15
16
17Paths and Join Pairs
18--------------------
19
20During the planning/optimizing process, we build "Path" trees representing
21the different ways of doing a query.  We select the cheapest Path that
22generates the desired relation and turn it into a Plan to pass to the
23executor.  (There is pretty nearly a one-to-one correspondence between the
24Path and Plan trees, but Path nodes omit info that won't be needed during
25planning, and include info needed for planning that won't be needed by the
26executor.)
27
28The optimizer builds a RelOptInfo structure for each base relation used in
29the query.  Base rels are either primitive tables, or subquery subselects
30that are planned via a separate recursive invocation of the planner.  A
31RelOptInfo is also built for each join relation that is considered during
32planning.  A join rel is simply a combination of base rels.  There is only
33one join RelOptInfo for any given set of baserels --- for example, the join
34{A B C} is represented by the same RelOptInfo no matter whether we build it
35by joining A and B first and then adding C, or joining B and C first and
36then adding A, etc.  These different means of building the joinrel are
37represented as Paths.  For each RelOptInfo we build a list of Paths that
38represent plausible ways to implement the scan or join of that relation.
39Once we've considered all the plausible Paths for a rel, we select the one
40that is cheapest according to the planner's cost estimates.  The final plan
41is derived from the cheapest Path for the RelOptInfo that includes all the
42base rels of the query.
43
44Possible Paths for a primitive table relation include plain old sequential
45scan, plus index scans for any indexes that exist on the table, plus bitmap
46index scans using one or more indexes.  Specialized RTE types, such as
47function RTEs, may have only one possible Path.
48
49Joins always occur using two RelOptInfos.  One is outer, the other inner.
50Outers drive lookups of values in the inner.  In a nested loop, lookups of
51values in the inner occur by scanning the inner path once per outer tuple
52to find each matching inner row.  In a mergejoin, inner and outer rows are
53ordered, and are accessed in order, so only one scan is required to perform
54the entire join: both inner and outer paths are scanned in-sync.  (There's
55not a lot of difference between inner and outer in a mergejoin...)  In a
56hashjoin, the inner is scanned first and all its rows are entered in a
57hashtable, then the outer is scanned and for each row we lookup the join
58key in the hashtable.
59
60A Path for a join relation is actually a tree structure, with the topmost
61Path node representing the last-applied join method.  It has left and right
62subpaths that represent the scan or join methods used for the two input
63relations.
64
65
66Join Tree Construction
67----------------------
68
69The optimizer generates optimal query plans by doing a more-or-less
70exhaustive search through the ways of executing the query.  The best Path
71tree is found by a recursive process:
72
731) Take each base relation in the query, and make a RelOptInfo structure
74for it.  Find each potentially useful way of accessing the relation,
75including sequential and index scans, and make Paths representing those
76ways.  All the Paths made for a given relation are placed in its
77RelOptInfo.pathlist.  (Actually, we discard Paths that are obviously
78inferior alternatives before they ever get into the pathlist --- what
79ends up in the pathlist is the cheapest way of generating each potentially
80useful sort ordering and parameterization of the relation.)  Also create a
81RelOptInfo.joininfo list including all the join clauses that involve this
82relation.  For example, the WHERE clause "tab1.col1 = tab2.col1" generates
83entries in both tab1 and tab2's joininfo lists.
84
85If we have only a single base relation in the query, we are done.
86Otherwise we have to figure out how to join the base relations into a
87single join relation.
88
892) Normally, any explicit JOIN clauses are "flattened" so that we just
90have a list of relations to join.  However, FULL OUTER JOIN clauses are
91never flattened, and other kinds of JOIN might not be either, if the
92flattening process is stopped by join_collapse_limit or from_collapse_limit
93restrictions.  Therefore, we end up with a planning problem that contains
94lists of relations to be joined in any order, where any individual item
95might be a sub-list that has to be joined together before we can consider
96joining it to its siblings.  We process these sub-problems recursively,
97bottom up.  Note that the join list structure constrains the possible join
98orders, but it doesn't constrain the join implementation method at each
99join (nestloop, merge, hash), nor does it say which rel is considered outer
100or inner at each join.  We consider all these possibilities in building
101Paths. We generate a Path for each feasible join method, and select the
102cheapest Path.
103
104For each planning problem, therefore, we will have a list of relations
105that are either base rels or joinrels constructed per sub-join-lists.
106We can join these rels together in any order the planner sees fit.
107The standard (non-GEQO) planner does this as follows:
108
109Consider joining each RelOptInfo to each other RelOptInfo for which there
110is a usable joinclause, and generate a Path for each possible join method
111for each such pair.  (If we have a RelOptInfo with no join clauses, we have
112no choice but to generate a clauseless Cartesian-product join; so we
113consider joining that rel to each other available rel.  But in the presence
114of join clauses we will only consider joins that use available join
115clauses.  Note that join-order restrictions induced by outer joins and
116IN/EXISTS clauses are also checked, to ensure that we find a workable join
117order in cases where those restrictions force a clauseless join to be done.)
118
119If we only had two relations in the list, we are done: we just pick
120the cheapest path for the join RelOptInfo.  If we had more than two, we now
121need to consider ways of joining join RelOptInfos to each other to make
122join RelOptInfos that represent more than two list items.
123
124The join tree is constructed using a "dynamic programming" algorithm:
125in the first pass (already described) we consider ways to create join rels
126representing exactly two list items.  The second pass considers ways
127to make join rels that represent exactly three list items; the next pass,
128four items, etc.  The last pass considers how to make the final join
129relation that includes all list items --- obviously there can be only one
130join rel at this top level, whereas there can be more than one join rel
131at lower levels.  At each level we use joins that follow available join
132clauses, if possible, just as described for the first level.
133
134For example:
135
136    SELECT  *
137    FROM    tab1, tab2, tab3, tab4
138    WHERE   tab1.col = tab2.col AND
139        tab2.col = tab3.col AND
140        tab3.col = tab4.col
141
142    Tables 1, 2, 3, and 4 are joined as:
143    {1 2},{2 3},{3 4}
144    {1 2 3},{2 3 4}
145    {1 2 3 4}
146    (other possibilities will be excluded for lack of join clauses)
147
148    SELECT  *
149    FROM    tab1, tab2, tab3, tab4
150    WHERE   tab1.col = tab2.col AND
151        tab1.col = tab3.col AND
152        tab1.col = tab4.col
153
154    Tables 1, 2, 3, and 4 are joined as:
155    {1 2},{1 3},{1 4}
156    {1 2 3},{1 3 4},{1 2 4}
157    {1 2 3 4}
158
159We consider left-handed plans (the outer rel of an upper join is a joinrel,
160but the inner is always a single list item); right-handed plans (outer rel
161is always a single item); and bushy plans (both inner and outer can be
162joins themselves).  For example, when building {1 2 3 4} we consider
163joining {1 2 3} to {4} (left-handed), {4} to {1 2 3} (right-handed), and
164{1 2} to {3 4} (bushy), among other choices.  Although the jointree
165scanning code produces these potential join combinations one at a time,
166all the ways to produce the same set of joined base rels will share the
167same RelOptInfo, so the paths produced from different join combinations
168that produce equivalent joinrels will compete in add_path().
169
170The dynamic-programming approach has an important property that's not
171immediately obvious: we will finish constructing all paths for a given
172relation before we construct any paths for relations containing that rel.
173This means that we can reliably identify the "cheapest path" for each rel
174before higher-level relations need to know that.  Also, we can safely
175discard a path when we find that another path for the same rel is better,
176without worrying that maybe there is already a reference to that path in
177some higher-level join path.  Without this, memory management for paths
178would be much more complicated.
179
180Once we have built the final join rel, we use either the cheapest path
181for it or the cheapest path with the desired ordering (if that's cheaper
182than applying a sort to the cheapest other path).
183
184If the query contains one-sided outer joins (LEFT or RIGHT joins), or
185IN or EXISTS WHERE clauses that were converted to semijoins or antijoins,
186then some of the possible join orders may be illegal.  These are excluded
187by having join_is_legal consult a side list of such "special" joins to see
188whether a proposed join is illegal.  (The same consultation allows it to
189see which join style should be applied for a valid join, ie, JOIN_INNER,
190JOIN_LEFT, etc.)
191
192
193Valid OUTER JOIN Optimizations
194------------------------------
195
196The planner's treatment of outer join reordering is based on the following
197identities:
198
1991.	(A leftjoin B on (Pab)) innerjoin C on (Pac)
200	= (A innerjoin C on (Pac)) leftjoin B on (Pab)
201
202where Pac is a predicate referencing A and C, etc (in this case, clearly
203Pac cannot reference B, or the transformation is nonsensical).
204
2052.	(A leftjoin B on (Pab)) leftjoin C on (Pac)
206	= (A leftjoin C on (Pac)) leftjoin B on (Pab)
207
2083.	(A leftjoin B on (Pab)) leftjoin C on (Pbc)
209	= A leftjoin (B leftjoin C on (Pbc)) on (Pab)
210
211Identity 3 only holds if predicate Pbc must fail for all-null B rows
212(that is, Pbc is strict for at least one column of B).  If Pbc is not
213strict, the first form might produce some rows with nonnull C columns
214where the second form would make those entries null.
215
216RIGHT JOIN is equivalent to LEFT JOIN after switching the two input
217tables, so the same identities work for right joins.
218
219An example of a case that does *not* work is moving an innerjoin into or
220out of the nullable side of an outer join:
221
222	A leftjoin (B join C on (Pbc)) on (Pab)
223	!= (A leftjoin B on (Pab)) join C on (Pbc)
224
225SEMI joins work a little bit differently.  A semijoin can be reassociated
226into or out of the lefthand side of another semijoin, left join, or
227antijoin, but not into or out of the righthand side.  Likewise, an inner
228join, left join, or antijoin can be reassociated into or out of the
229lefthand side of a semijoin, but not into or out of the righthand side.
230
231ANTI joins work approximately like LEFT joins, except that identity 3
232fails if the join to C is an antijoin (even if Pbc is strict, and in
233both the cases where the other join is a leftjoin and where it is an
234antijoin).  So we can't reorder antijoins into or out of the RHS of a
235leftjoin or antijoin, even if the relevant clause is strict.
236
237The current code does not attempt to re-order FULL JOINs at all.
238FULL JOIN ordering is enforced by not collapsing FULL JOIN nodes when
239translating the jointree to "joinlist" representation.  Other types of
240JOIN nodes are normally collapsed so that they participate fully in the
241join order search.  To avoid generating illegal join orders, the planner
242creates a SpecialJoinInfo node for each non-inner join, and join_is_legal
243checks this list to decide if a proposed join is legal.
244
245What we store in SpecialJoinInfo nodes are the minimum sets of Relids
246required on each side of the join to form the outer join.  Note that
247these are minimums; there's no explicit maximum, since joining other
248rels to the OJ's syntactic rels may be legal.  Per identities 1 and 2,
249non-FULL joins can be freely associated into the lefthand side of an
250OJ, but in some cases they can't be associated into the righthand side.
251So the restriction enforced by join_is_legal is that a proposed join
252can't join a rel within or partly within an RHS boundary to one outside
253the boundary, unless the proposed join is a LEFT join that can associate
254into the SpecialJoinInfo's RHS using identity 3.
255
256The use of minimum Relid sets has some pitfalls; consider a query like
257	A leftjoin (B leftjoin (C innerjoin D) on (Pbcd)) on Pa
258where Pa doesn't mention B/C/D at all.  In this case a naive computation
259would give the upper leftjoin's min LHS as {A} and min RHS as {C,D} (since
260we know that the innerjoin can't associate out of the leftjoin's RHS, and
261enforce that by including its relids in the leftjoin's min RHS).  And the
262lower leftjoin has min LHS of {B} and min RHS of {C,D}.  Given such
263information, join_is_legal would think it's okay to associate the upper
264join into the lower join's RHS, transforming the query to
265	B leftjoin (A leftjoin (C innerjoin D) on Pa) on (Pbcd)
266which yields totally wrong answers.  We prevent that by forcing the min RHS
267for the upper join to include B.  This is perhaps overly restrictive, but
268such cases don't arise often so it's not clear that it's worth developing a
269more complicated system.
270
271
272Pulling Up Subqueries
273---------------------
274
275As we described above, a subquery appearing in the range table is planned
276independently and treated as a "black box" during planning of the outer
277query.  This is necessary when the subquery uses features such as
278aggregates, GROUP, or DISTINCT.  But if the subquery is just a simple
279scan or join, treating the subquery as a black box may produce a poor plan
280compared to considering it as part of the entire plan search space.
281Therefore, at the start of the planning process the planner looks for
282simple subqueries and pulls them up into the main query's jointree.
283
284Pulling up a subquery may result in FROM-list joins appearing below the top
285of the join tree.  Each FROM-list is planned using the dynamic-programming
286search method described above.
287
288If pulling up a subquery produces a FROM-list as a direct child of another
289FROM-list, then we can merge the two FROM-lists together.  Once that's
290done, the subquery is an absolutely integral part of the outer query and
291will not constrain the join tree search space at all.  However, that could
292result in unpleasant growth of planning time, since the dynamic-programming
293search has runtime exponential in the number of FROM-items considered.
294Therefore, we don't merge FROM-lists if the result would have too many
295FROM-items in one list.
296
297
298Optimizer Functions
299-------------------
300
301The primary entry point is planner().
302
303planner()
304set up for recursive handling of subqueries
305-subquery_planner()
306 pull up sublinks and subqueries from rangetable, if possible
307 canonicalize qual
308     Attempt to simplify WHERE clause to the most useful form; this includes
309     flattening nested AND/ORs and detecting clauses that are duplicated in
310     different branches of an OR.
311 simplify constant expressions
312 process sublinks
313 convert Vars of outer query levels into Params
314--grouping_planner()
315  preprocess target list for non-SELECT queries
316  handle UNION/INTERSECT/EXCEPT, GROUP BY, HAVING, aggregates,
317	ORDER BY, DISTINCT, LIMIT
318--query_planner()
319   make list of base relations used in query
320   split up the qual into restrictions (a=1) and joins (b=c)
321   find qual clauses that enable merge and hash joins
322----make_one_rel()
323     set_base_rel_pathlist()
324      find seqscan and all index paths for each base relation
325      find selectivity of columns used in joins
326     make_rel_from_joinlist()
327      hand off join subproblems to a plugin, GEQO, or standard_join_search()
328-----standard_join_search()
329      call join_search_one_level() for each level of join tree needed
330      join_search_one_level():
331        For each joinrel of the prior level, do make_rels_by_clause_joins()
332        if it has join clauses, or make_rels_by_clauseless_joins() if not.
333        Also generate "bushy plan" joins between joinrels of lower levels.
334      Back at standard_join_search(), generate gather paths if needed for
335      each newly constructed joinrel, then apply set_cheapest() to extract
336      the cheapest path for it.
337      Loop back if this wasn't the top join level.
338  Back at grouping_planner:
339  do grouping (GROUP BY) and aggregation
340  do window functions
341  make unique (DISTINCT)
342  do sorting (ORDER BY)
343  do limit (LIMIT/OFFSET)
344Back at planner():
345convert finished Path tree into a Plan tree
346do final cleanup after planning
347
348
349Optimizer Data Structures
350-------------------------
351
352PlannerGlobal   - global information for a single planner invocation
353
354PlannerInfo     - information for planning a particular Query (we make
355                  a separate PlannerInfo node for each sub-Query)
356
357RelOptInfo      - a relation or joined relations
358
359 RestrictInfo   - WHERE clauses, like "x = 3" or "y = z"
360                  (note the same structure is used for restriction and
361                   join clauses)
362
363 Path           - every way to generate a RelOptInfo(sequential,index,joins)
364  SeqScan       - represents a sequential scan plan
365  IndexPath     - index scan
366  BitmapHeapPath - top of a bitmapped index scan
367  TidPath       - scan by CTID
368  SubqueryScanPath - scan a subquery-in-FROM
369  ForeignPath   - scan a foreign table, foreign join or foreign upper-relation
370  CustomPath    - for custom scan providers
371  AppendPath    - append multiple subpaths together
372  MergeAppendPath - merge multiple subpaths, preserving their common sort order
373  ResultPath    - a childless Result plan node (used for FROM-less SELECT)
374  MaterialPath  - a Material plan node
375  UniquePath    - remove duplicate rows (either by hashing or sorting)
376  GatherPath    - collect the results of parallel workers
377  ProjectionPath - a Result plan node with child (used for projection)
378  SortPath      - a Sort plan node applied to some sub-path
379  GroupPath     - a Group plan node applied to some sub-path
380  UpperUniquePath - a Unique plan node applied to some sub-path
381  AggPath       - an Agg plan node applied to some sub-path
382  GroupingSetsPath - an Agg plan node used to implement GROUPING SETS
383  MinMaxAggPath - a Result plan node with subplans performing MIN/MAX
384  WindowAggPath - a WindowAgg plan node applied to some sub-path
385  SetOpPath     - a SetOp plan node applied to some sub-path
386  RecursiveUnionPath - a RecursiveUnion plan node applied to two sub-paths
387  LockRowsPath  - a LockRows plan node applied to some sub-path
388  ModifyTablePath - a ModifyTable plan node applied to some sub-path(s)
389  LimitPath     - a Limit plan node applied to some sub-path
390  NestPath      - nested-loop joins
391  MergePath     - merge joins
392  HashPath      - hash joins
393
394 EquivalenceClass - a data structure representing a set of values known equal
395
396 PathKey        - a data structure representing the sort ordering of a path
397
398The optimizer spends a good deal of its time worrying about the ordering
399of the tuples returned by a path.  The reason this is useful is that by
400knowing the sort ordering of a path, we may be able to use that path as
401the left or right input of a mergejoin and avoid an explicit sort step.
402Nestloops and hash joins don't really care what the order of their inputs
403is, but mergejoin needs suitably ordered inputs.  Therefore, all paths
404generated during the optimization process are marked with their sort order
405(to the extent that it is known) for possible use by a higher-level merge.
406
407It is also possible to avoid an explicit sort step to implement a user's
408ORDER BY clause if the final path has the right ordering already, so the
409sort ordering is of interest even at the top level.  grouping_planner() will
410look for the cheapest path with a sort order matching the desired order,
411then compare its cost to the cost of using the cheapest-overall path and
412doing an explicit sort on that.
413
414When we are generating paths for a particular RelOptInfo, we discard a path
415if it is more expensive than another known path that has the same or better
416sort order.  We will never discard a path that is the only known way to
417achieve a given sort order (without an explicit sort, that is).  In this
418way, the next level up will have the maximum freedom to build mergejoins
419without sorting, since it can pick from any of the paths retained for its
420inputs.
421
422
423EquivalenceClasses
424------------------
425
426During the deconstruct_jointree() scan of the query's qual clauses, we look
427for mergejoinable equality clauses A = B whose applicability is not delayed
428by an outer join; these are called "equivalence clauses".  When we find
429one, we create an EquivalenceClass containing the expressions A and B to
430record this knowledge.  If we later find another equivalence clause B = C,
431we add C to the existing EquivalenceClass for {A B}; this may require
432merging two existing EquivalenceClasses.  At the end of the scan, we have
433sets of values that are known all transitively equal to each other.  We can
434therefore use a comparison of any pair of the values as a restriction or
435join clause (when these values are available at the scan or join, of
436course); furthermore, we need test only one such comparison, not all of
437them.  Therefore, equivalence clauses are removed from the standard qual
438distribution process.  Instead, when preparing a restriction or join clause
439list, we examine each EquivalenceClass to see if it can contribute a
440clause, and if so we select an appropriate pair of values to compare.  For
441example, if we are trying to join A's relation to C's, we can generate the
442clause A = C, even though this appeared nowhere explicitly in the original
443query.  This may allow us to explore join paths that otherwise would have
444been rejected as requiring Cartesian-product joins.
445
446Sometimes an EquivalenceClass may contain a pseudo-constant expression
447(i.e., one not containing Vars or Aggs of the current query level, nor
448volatile functions).  In this case we do not follow the policy of
449dynamically generating join clauses: instead, we dynamically generate
450restriction clauses "var = const" wherever one of the variable members of
451the class can first be computed.  For example, if we have A = B and B = 42,
452we effectively generate the restriction clauses A = 42 and B = 42, and then
453we need not bother with explicitly testing the join clause A = B when the
454relations are joined.  In effect, all the class members can be tested at
455relation-scan level and there's never a need for join tests.
456
457The precise technical interpretation of an EquivalenceClass is that it
458asserts that at any plan node where more than one of its member values
459can be computed, output rows in which the values are not all equal may
460be discarded without affecting the query result.  (We require all levels
461of the plan to enforce EquivalenceClasses, hence a join need not recheck
462equality of values that were computable by one of its children.)  For an
463ordinary EquivalenceClass that is "valid everywhere", we can further infer
464that the values are all non-null, because all mergejoinable operators are
465strict.  However, we also allow equivalence clauses that appear below the
466nullable side of an outer join to form EquivalenceClasses; for these
467classes, the interpretation is that either all the values are equal, or
468all (except pseudo-constants) have gone to null.  (This requires a
469limitation that non-constant members be strict, else they might not go
470to null when the other members do.)  Consider for example
471
472	SELECT *
473	  FROM a LEFT JOIN
474	       (SELECT * FROM b JOIN c ON b.y = c.z WHERE b.y = 10) ss
475	       ON a.x = ss.y
476	  WHERE a.x = 42;
477
478We can form the below-outer-join EquivalenceClass {b.y c.z 10} and thereby
479apply c.z = 10 while scanning c.  (The reason we disallow outerjoin-delayed
480clauses from forming EquivalenceClasses is exactly that we want to be able
481to push any derived clauses as far down as possible.)  But once above the
482outer join it's no longer necessarily the case that b.y = 10, and thus we
483cannot use such EquivalenceClasses to conclude that sorting is unnecessary
484(see discussion of PathKeys below).
485
486In this example, notice also that a.x = ss.y (really a.x = b.y) is not an
487equivalence clause because its applicability to b is delayed by the outer
488join; thus we do not try to insert b.y into the equivalence class {a.x 42}.
489But since we see that a.x has been equated to 42 above the outer join, we
490are able to form a below-outer-join class {b.y 42}; this restriction can be
491added because no b/c row not having b.y = 42 can contribute to the result
492of the outer join, and so we need not compute such rows.  Now this class
493will get merged with {b.y c.z 10}, leading to the contradiction 10 = 42,
494which lets the planner deduce that the b/c join need not be computed at all
495because none of its rows can contribute to the outer join.  (This gets
496implemented as a gating Result filter, since more usually the potential
497contradiction involves Param values rather than just Consts, and thus has
498to be checked at runtime.)
499
500To aid in determining the sort ordering(s) that can work with a mergejoin,
501we mark each mergejoinable clause with the EquivalenceClasses of its left
502and right inputs.  For an equivalence clause, these are of course the same
503EquivalenceClass.  For a non-equivalence mergejoinable clause (such as an
504outer-join qualification), we generate two separate EquivalenceClasses for
505the left and right inputs.  This may result in creating single-item
506equivalence "classes", though of course these are still subject to merging
507if other equivalence clauses are later found to bear on the same
508expressions.
509
510Another way that we may form a single-item EquivalenceClass is in creation
511of a PathKey to represent a desired sort order (see below).  This is a bit
512different from the above cases because such an EquivalenceClass might
513contain an aggregate function or volatile expression.  (A clause containing
514a volatile function will never be considered mergejoinable, even if its top
515operator is mergejoinable, so there is no way for a volatile expression to
516get into EquivalenceClasses otherwise.  Aggregates are disallowed in WHERE
517altogether, so will never be found in a mergejoinable clause.)  This is just
518a convenience to maintain a uniform PathKey representation: such an
519EquivalenceClass will never be merged with any other.  Note in particular
520that a single-item EquivalenceClass {a.x} is *not* meant to imply an
521assertion that a.x = a.x; the practical effect of this is that a.x could
522be NULL.
523
524An EquivalenceClass also contains a list of btree opfamily OIDs, which
525determines what the equalities it represents actually "mean".  All the
526equivalence clauses that contribute to an EquivalenceClass must have
527equality operators that belong to the same set of opfamilies.  (Note: most
528of the time, a particular equality operator belongs to only one family, but
529it's possible that it belongs to more than one.  We keep track of all the
530families to ensure that we can make use of an index belonging to any one of
531the families for mergejoin purposes.)
532
533An EquivalenceClass can contain "em_is_child" members, which are copies
534of members that contain appendrel parent relation Vars, transposed to
535contain the equivalent child-relation variables or expressions.  These
536members are *not* full-fledged members of the EquivalenceClass and do not
537affect the class's overall properties at all.  They are kept only to
538simplify matching of child-relation expressions to EquivalenceClasses.
539Most operations on EquivalenceClasses should ignore child members.
540
541
542PathKeys
543--------
544
545The PathKeys data structure represents what is known about the sort order
546of the tuples generated by a particular Path.  A path's pathkeys field is a
547list of PathKey nodes, where the n'th item represents the n'th sort key of
548the result.  Each PathKey contains these fields:
549
550	* a reference to an EquivalenceClass
551	* a btree opfamily OID (must match one of those in the EC)
552	* a sort direction (ascending or descending)
553	* a nulls-first-or-last flag
554
555The EquivalenceClass represents the value being sorted on.  Since the
556various members of an EquivalenceClass are known equal according to the
557opfamily, we can consider a path sorted by any one of them to be sorted by
558any other too; this is what justifies referencing the whole
559EquivalenceClass rather than just one member of it.
560
561In single/base relation RelOptInfo's, the Paths represent various ways
562of scanning the relation and the resulting ordering of the tuples.
563Sequential scan Paths have NIL pathkeys, indicating no known ordering.
564Index scans have Path.pathkeys that represent the chosen index's ordering,
565if any.  A single-key index would create a single-PathKey list, while a
566multi-column index generates a list with one element per index column.
567(Actually, since an index can be scanned either forward or backward, there
568are two possible sort orders and two possible PathKey lists it can
569generate.)
570
571Note that a bitmap scan has NIL pathkeys since we can say nothing about
572the overall order of its result.  Also, an indexscan on an unordered type
573of index generates NIL pathkeys.  However, we can always create a pathkey
574by doing an explicit sort.  The pathkeys for a Sort plan's output just
575represent the sort key fields and the ordering operators used.
576
577Things get more interesting when we consider joins.  Suppose we do a
578mergejoin between A and B using the mergeclause A.X = B.Y.  The output
579of the mergejoin is sorted by X --- but it is also sorted by Y.  Again,
580this can be represented by a PathKey referencing an EquivalenceClass
581containing both X and Y.
582
583With a little further thought, it becomes apparent that nestloop joins
584can also produce sorted output.  For example, if we do a nestloop join
585between outer relation A and inner relation B, then any pathkeys relevant
586to A are still valid for the join result: we have not altered the order of
587the tuples from A.  Even more interesting, if there was an equivalence clause
588A.X=B.Y, and A.X was a pathkey for the outer relation A, then we can assert
589that B.Y is a pathkey for the join result; X was ordered before and still
590is, and the joined values of Y are equal to the joined values of X, so Y
591must now be ordered too.  This is true even though we used neither an
592explicit sort nor a mergejoin on Y.  (Note: hash joins cannot be counted
593on to preserve the order of their outer relation, because the executor
594might decide to "batch" the join, so we always set pathkeys to NIL for
595a hashjoin path.)  Exception: a RIGHT or FULL join doesn't preserve the
596ordering of its outer relation, because it might insert nulls at random
597points in the ordering.
598
599In general, we can justify using EquivalenceClasses as the basis for
600pathkeys because, whenever we scan a relation containing multiple
601EquivalenceClass members or join two relations each containing
602EquivalenceClass members, we apply restriction or join clauses derived from
603the EquivalenceClass.  This guarantees that any two values listed in the
604EquivalenceClass are in fact equal in all tuples emitted by the scan or
605join, and therefore that if the tuples are sorted by one of the values,
606they can be considered sorted by any other as well.  It does not matter
607whether the test clause is used as a mergeclause, or merely enforced
608after-the-fact as a qpqual filter.
609
610Note that there is no particular difficulty in labeling a path's sort
611order with a PathKey referencing an EquivalenceClass that contains
612variables not yet joined into the path's output.  We can simply ignore
613such entries as not being relevant (yet).  This makes it possible to
614use the same EquivalenceClasses throughout the join planning process.
615In fact, by being careful not to generate multiple identical PathKey
616objects, we can reduce comparison of EquivalenceClasses and PathKeys
617to simple pointer comparison, which is a huge savings because add_path
618has to make a large number of PathKey comparisons in deciding whether
619competing Paths are equivalently sorted.
620
621Pathkeys are also useful to represent an ordering that we wish to achieve,
622since they are easily compared to the pathkeys of a potential candidate
623path.  So, SortGroupClause lists are turned into pathkeys lists for use
624inside the optimizer.
625
626An additional refinement we can make is to insist that canonical pathkey
627lists (sort orderings) do not mention the same EquivalenceClass more than
628once.  For example, in all these cases the second sort column is redundant,
629because it cannot distinguish values that are the same according to the
630first sort column:
631	SELECT ... ORDER BY x, x
632	SELECT ... ORDER BY x, x DESC
633	SELECT ... WHERE x = y ORDER BY x, y
634Although a user probably wouldn't write "ORDER BY x,x" directly, such
635redundancies are more probable once equivalence classes have been
636considered.  Also, the system may generate redundant pathkey lists when
637computing the sort ordering needed for a mergejoin.  By eliminating the
638redundancy, we save time and improve planning, since the planner will more
639easily recognize equivalent orderings as being equivalent.
640
641Another interesting property is that if the underlying EquivalenceClass
642contains a constant and is not below an outer join, then the pathkey is
643completely redundant and need not be sorted by at all!  Every row must
644contain the same constant value, so there's no need to sort.  (If the EC is
645below an outer join, we still have to sort, since some of the rows might
646have gone to null and others not.  In this case we must be careful to pick
647a non-const member to sort by.  The assumption that all the non-const
648members go to null at the same plan level is critical here, else they might
649not produce the same sort order.)  This might seem pointless because users
650are unlikely to write "... WHERE x = 42 ORDER BY x", but it allows us to
651recognize when particular index columns are irrelevant to the sort order:
652if we have "... WHERE x = 42 ORDER BY y", scanning an index on (x,y)
653produces correctly ordered data without a sort step.  We used to have very
654ugly ad-hoc code to recognize that in limited contexts, but discarding
655constant ECs from pathkeys makes it happen cleanly and automatically.
656
657You might object that a below-outer-join EquivalenceClass doesn't always
658represent the same values at every level of the join tree, and so using
659it to uniquely identify a sort order is dubious.  This is true, but we
660can avoid dealing with the fact explicitly because we always consider that
661an outer join destroys any ordering of its nullable inputs.  Thus, even
662if a path was sorted by {a.x} below an outer join, we'll re-sort if that
663sort ordering was important; and so using the same PathKey for both sort
664orderings doesn't create any real problem.
665
666
667Order of processing for EquivalenceClasses and PathKeys
668-------------------------------------------------------
669
670As alluded to above, there is a specific sequence of phases in the
671processing of EquivalenceClasses and PathKeys during planning.  During the
672initial scanning of the query's quals (deconstruct_jointree followed by
673reconsider_outer_join_clauses), we construct EquivalenceClasses based on
674mergejoinable clauses found in the quals.  At the end of this process,
675we know all we can know about equivalence of different variables, so
676subsequently there will be no further merging of EquivalenceClasses.
677At that point it is possible to consider the EquivalenceClasses as
678"canonical" and build canonical PathKeys that reference them.  At this
679time we construct PathKeys for the query's ORDER BY and related clauses.
680(Any ordering expressions that do not appear elsewhere will result in
681the creation of new EquivalenceClasses, but this cannot result in merging
682existing classes, so canonical-ness is not lost.)
683
684Because all the EquivalenceClasses are known before we begin path
685generation, we can use them as a guide to which indexes are of interest:
686if an index's column is not mentioned in any EquivalenceClass then that
687index's sort order cannot possibly be helpful for the query.  This allows
688short-circuiting of much of the processing of create_index_paths() for
689irrelevant indexes.
690
691There are some cases where planner.c constructs additional
692EquivalenceClasses and PathKeys after query_planner has completed.
693In these cases, the extra ECs/PKs are needed to represent sort orders
694that were not considered during query_planner.  Such situations should be
695minimized since it is impossible for query_planner to return a plan
696producing such a sort order, meaning an explicit sort will always be needed.
697Currently this happens only for queries involving multiple window functions
698with different orderings, for which extra sorts are needed anyway.
699
700
701Parameterized Paths
702-------------------
703
704The naive way to join two relations using a clause like WHERE A.X = B.Y
705is to generate a nestloop plan like this:
706
707	NestLoop
708		Filter: A.X = B.Y
709		-> Seq Scan on A
710		-> Seq Scan on B
711
712We can make this better by using a merge or hash join, but it still
713requires scanning all of both input relations.  If A is very small and B is
714very large, but there is an index on B.Y, it can be enormously better to do
715something like this:
716
717	NestLoop
718		-> Seq Scan on A
719		-> Index Scan using B_Y_IDX on B
720			Index Condition: B.Y = A.X
721
722Here, we are expecting that for each row scanned from A, the nestloop
723plan node will pass down the current value of A.X into the scan of B.
724That allows the indexscan to treat A.X as a constant for any one
725invocation, and thereby use it as an index key.  This is the only plan type
726that can avoid fetching all of B, and for small numbers of rows coming from
727A, that will dominate every other consideration.  (As A gets larger, this
728gets less attractive, and eventually a merge or hash join will win instead.
729So we have to cost out all the alternatives to decide what to do.)
730
731It can be useful for the parameter value to be passed down through
732intermediate layers of joins, for example:
733
734	NestLoop
735		-> Seq Scan on A
736		Hash Join
737			Join Condition: B.Y = C.W
738			-> Seq Scan on B
739			-> Index Scan using C_Z_IDX on C
740				Index Condition: C.Z = A.X
741
742If all joins are plain inner joins then this is usually unnecessary,
743because it's possible to reorder the joins so that a parameter is used
744immediately below the nestloop node that provides it.  But in the
745presence of outer joins, such join reordering may not be possible.
746
747Also, the bottom-level scan might require parameters from more than one
748other relation.  In principle we could join the other relations first
749so that all the parameters are supplied from a single nestloop level.
750But if those other relations have no join clause in common (which is
751common in star-schema queries for instance), the planner won't consider
752joining them directly to each other.  In such a case we need to be able
753to create a plan like
754
755    NestLoop
756        -> Seq Scan on SmallTable1 A
757        NestLoop
758            -> Seq Scan on SmallTable2 B
759            NestLoop
760                -> Index Scan using XYIndex on LargeTable C
761                      Index Condition: C.X = A.AID and C.Y = B.BID
762
763so we should be willing to pass down A.AID through a join even though
764there is no join order constraint forcing the plan to look like this.
765
766Before version 9.2, Postgres used ad-hoc methods for planning and
767executing nestloop queries of this kind, and those methods could not
768handle passing parameters down through multiple join levels.
769
770To plan such queries, we now use a notion of a "parameterized path",
771which is a path that makes use of a join clause to a relation that's not
772scanned by the path.  In the example two above, we would construct a
773path representing the possibility of doing this:
774
775	-> Index Scan using C_Z_IDX on C
776		Index Condition: C.Z = A.X
777
778This path will be marked as being parameterized by relation A.  (Note that
779this is only one of the possible access paths for C; we'd still have a
780plain unparameterized seqscan, and perhaps other possibilities.)  The
781parameterization marker does not prevent joining the path to B, so one of
782the paths generated for the joinrel {B C} will represent
783
784	Hash Join
785		Join Condition: B.Y = C.W
786		-> Seq Scan on B
787		-> Index Scan using C_Z_IDX on C
788			Index Condition: C.Z = A.X
789
790This path is still marked as being parameterized by A.  When we attempt to
791join {B C} to A to form the complete join tree, such a path can only be
792used as the inner side of a nestloop join: it will be ignored for other
793possible join types.  So we will form a join path representing the query
794plan shown above, and it will compete in the usual way with paths built
795from non-parameterized scans.
796
797While all ordinary paths for a particular relation generate the same set
798of rows (since they must all apply the same set of restriction clauses),
799parameterized paths typically generate fewer rows than less-parameterized
800paths, since they have additional clauses to work with.  This means we
801must consider the number of rows generated as an additional figure of
802merit.  A path that costs more than another, but generates fewer rows,
803must be kept since the smaller number of rows might save work at some
804intermediate join level.  (It would not save anything if joined
805immediately to the source of the parameters.)
806
807To keep cost estimation rules relatively simple, we make an implementation
808restriction that all paths for a given relation of the same parameterization
809(i.e., the same set of outer relations supplying parameters) must have the
810same rowcount estimate.  This is justified by insisting that each such path
811apply *all* join clauses that are available with the named outer relations.
812Different paths might, for instance, choose different join clauses to use
813as index clauses; but they must then apply any other join clauses available
814from the same outer relations as filter conditions, so that the set of rows
815returned is held constant.  This restriction doesn't degrade the quality of
816the finished plan: it amounts to saying that we should always push down
817movable join clauses to the lowest possible evaluation level, which is a
818good thing anyway.  The restriction is useful in particular to support
819pre-filtering of join paths in add_path_precheck.  Without this rule we
820could never reject a parameterized path in advance of computing its rowcount
821estimate, which would greatly reduce the value of the pre-filter mechanism.
822
823To limit planning time, we have to avoid generating an unreasonably large
824number of parameterized paths.  We do this by only generating parameterized
825relation scan paths for index scans, and then only for indexes for which
826suitable join clauses are available.  There are also heuristics in join
827planning that try to limit the number of parameterized paths considered.
828
829In particular, there's been a deliberate policy decision to favor hash
830joins over merge joins for parameterized join steps (those occurring below
831a nestloop that provides parameters to the lower join's inputs).  While we
832do not ignore merge joins entirely, joinpath.c does not fully explore the
833space of potential merge joins with parameterized inputs.  Also, add_path
834treats parameterized paths as having no pathkeys, so that they compete
835only on cost and rowcount; they don't get preference for producing a
836special sort order.  This creates additional bias against merge joins,
837since we might discard a path that could have been useful for performing
838a merge without an explicit sort step.  Since a parameterized path must
839ultimately be used on the inside of a nestloop, where its sort order is
840uninteresting, these choices do not affect any requirement for the final
841output order of a query --- they only make it harder to use a merge join
842at a lower level.  The savings in planning work justifies that.
843
844Similarly, parameterized paths do not normally get preference in add_path
845for having cheap startup cost; that's seldom of much value when on the
846inside of a nestloop, so it seems not worth keeping extra paths solely for
847that.  An exception occurs for parameterized paths for the RHS relation of
848a SEMI or ANTI join: in those cases, we can stop the inner scan after the
849first match, so it's primarily startup not total cost that we care about.
850
851
852LATERAL subqueries
853------------------
854
855As of 9.3 we support SQL-standard LATERAL references from subqueries in
856FROM (and also functions in FROM).  The planner implements these by
857generating parameterized paths for any RTE that contains lateral
858references.  In such cases, *all* paths for that relation will be
859parameterized by at least the set of relations used in its lateral
860references.  (And in turn, join relations including such a subquery might
861not have any unparameterized paths.)  All the other comments made above for
862parameterized paths still apply, though; in particular, each such path is
863still expected to enforce any join clauses that can be pushed down to it,
864so that all paths of the same parameterization have the same rowcount.
865
866We also allow LATERAL subqueries to be flattened (pulled up into the parent
867query) by the optimizer, but only when this does not introduce lateral
868references into JOIN/ON quals that would refer to relations outside the
869lowest outer join at/above that qual.  The semantics of such a qual would
870be unclear.  Note that even with this restriction, pullup of a LATERAL
871subquery can result in creating PlaceHolderVars that contain lateral
872references to relations outside their syntactic scope.  We still evaluate
873such PHVs at their syntactic location or lower, but the presence of such a
874PHV in the quals or targetlist of a plan node requires that node to appear
875on the inside of a nestloop join relative to the rel(s) supplying the
876lateral reference.  (Perhaps now that that stuff works, we could relax the
877pullup restriction?)
878
879
880Post scan/join planning
881-----------------------
882
883So far we have discussed only scan/join planning, that is, implementation
884of the FROM and WHERE clauses of a SQL query.  But the planner must also
885determine how to deal with GROUP BY, aggregation, and other higher-level
886features of queries; and in many cases there are multiple ways to do these
887steps and thus opportunities for optimization choices.  These steps, like
888scan/join planning, are handled by constructing Paths representing the
889different ways to do a step, then choosing the cheapest Path.
890
891Since all Paths require a RelOptInfo as "parent", we create RelOptInfos
892representing the outputs of these upper-level processing steps.  These
893RelOptInfos are mostly dummy, but their pathlist lists hold all the Paths
894considered useful for each step.  Currently, we may create these types of
895additional RelOptInfos during upper-level planning:
896
897UPPERREL_SETOP		result of UNION/INTERSECT/EXCEPT, if any
898UPPERREL_GROUP_AGG	result of grouping/aggregation, if any
899UPPERREL_WINDOW		result of window functions, if any
900UPPERREL_DISTINCT	result of "SELECT DISTINCT", if any
901UPPERREL_ORDERED	result of ORDER BY, if any
902UPPERREL_FINAL		result of any remaining top-level actions
903
904UPPERREL_FINAL is used to represent any final processing steps, currently
905LockRows (SELECT FOR UPDATE), LIMIT/OFFSET, and ModifyTable.  There is no
906flexibility about the order in which these steps are done, and thus no need
907to subdivide this stage more finely.
908
909These "upper relations" are identified by the UPPERREL enum values shown
910above, plus a relids set, which allows there to be more than one upperrel
911of the same kind.  We use NULL for the relids if there's no need for more
912than one upperrel of the same kind.  Currently, in fact, the relids set
913is vestigial because it's always NULL, but that's expected to change in
914the future.  For example, in planning set operations, we might need the
915relids to denote which subset of the leaf SELECTs has been combined in a
916particular group of Paths that are competing with each other.
917
918The result of subquery_planner() is always returned as a set of Paths
919stored in the UPPERREL_FINAL rel with NULL relids.  The other types of
920upperrels are created only if needed for the particular query.
921
922
923Parallel Query and Partial Paths
924--------------------------------
925
926Parallel query involves dividing up the work that needs to be performed
927either by an entire query or some portion of the query in such a way that
928some of that work can be done by one or more worker processes, which are
929called parallel workers.  Parallel workers are a subtype of dynamic
930background workers; see src/backend/access/transam/README.parallel for a
931fuller description.  Academic literature on parallel query suggests that
932that parallel execution strategies can be divided into essentially two
933categories: pipelined parallelism, where the execution of the query is
934divided into multiple stages and each stage is handled by a separate
935process; and partitioning parallelism, where the data is split between
936multiple processes and each process handles a subset of it.  The
937literature, however, suggests that gains from pipeline parallelism are
938often very limited due to the difficulty of avoiding pipeline stalls.
939Consequently, we do not currently attempt to generate query plans that
940use this technique.
941
942Instead, we focus on partitioning parallelism, which does not require
943that the underlying table be partitioned.  It only requires that (1)
944there is some method of dividing the data from at least one of the base
945tables involved in the relation across multiple processes, (2) allowing
946each process to handle its own portion of the data, and then (3)
947collecting the results.  Requirements (2) and (3) is satisfied by the
948executor node Gather, which launches any number of worker processes and
949executes its single child plan in all of them (and perhaps in the leader
950also, if the children aren't generating enough data to keep the leader
951busy).  Requirement (1) is handled by the SeqScan node: when invoked
952with parallel_aware = true, this node will, in effect, partition the
953table on a block by block basis, returning a subset of the tuples from
954the relation in each worker where that SeqScan is executed.  A similar
955scheme could be (and probably should be) implemented for bitmap heap
956scans.
957
958Just as we do for non-parallel access methods, we build Paths to
959represent access strategies that can be used in a parallel plan.  These
960are, in essence, the same strategies that are available in the
961non-parallel plan, but there is an important difference: a path that
962will run beneath a Gather node returns only a subset of the query
963results in each worker, not all of them.  To form a path that can
964actually be executed, the (rather large) cost of the Gather node must be
965accounted for.  For this reason among others, paths intended to run
966beneath a Gather node - which we call "partial" paths since they return
967only a subset of the results in each worker - must be kept separate from
968ordinary paths (see RelOptInfo's partial_pathlist and the function
969add_partial_path).
970
971One of the keys to making parallel query effective is to run as much of
972the query in parallel as possible.  Therefore, we expect it to generally
973be desirable to postpone the Gather stage until as near to the top of the
974plan as possible.  Expanding the range of cases in which more work can be
975pushed below the Gather (and costing them accurately) is likely to keep us
976busy for a long time to come.
977