~ubuntu-branches/ubuntu/trusty/postgresql-9.3/trusty-updates

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>Controlling the Planner with Explicit JOIN Clauses</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 9.3.13 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="Performance Tips"
HREF="performance-tips.html"><LINK
REL="PREVIOUS"
TITLE="Statistics Used by the Planner"
HREF="planner-stats.html"><LINK
REL="NEXT"
TITLE="Populating a Database"
HREF="populate.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2016-05-09T21:13:26"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
><A
HREF="index.html"
>PostgreSQL 9.3.13 Documentation</A
></TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
TITLE="Statistics Used by the Planner"
HREF="planner-stats.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="performance-tips.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 14. Performance Tips</TD
><TD
WIDTH="20%"
ALIGN="right"
VALIGN="top"
><A
TITLE="Populating a Database"
HREF="populate.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="EXPLICIT-JOINS"
>14.3. Controlling the Planner with Explicit <TT
CLASS="LITERAL"
>JOIN</TT
> Clauses</A
></H1
><P
>   It is possible
   to control the query planner to some extent by using the explicit <TT
CLASS="LITERAL"
>JOIN</TT
>
   syntax.  To see why this matters, we first need some background.
  </P
><P
>   In a simple join query, such as:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM a, b, c WHERE a.id = b.id AND b.ref = c.id;</PRE
><P>
   the planner is free to join the given tables in any order.  For
   example, it could generate a query plan that joins A to B, using
   the <TT
CLASS="LITERAL"
>WHERE</TT
> condition <TT
CLASS="LITERAL"
>a.id = b.id</TT
>, and then
   joins C to this joined table, using the other <TT
CLASS="LITERAL"
>WHERE</TT
>
   condition.  Or it could join B to C and then join A to that result.
   Or it could join A to C and then join them with B &mdash; but that
   would be inefficient, since the full Cartesian product of A and C
   would have to be formed, there being no applicable condition in the
   <TT
CLASS="LITERAL"
>WHERE</TT
> clause to allow optimization of the join.  (All
   joins in the <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> executor happen
   between two input tables, so it's necessary to build up the result
   in one or another of these fashions.)  The important point is that
   these different join possibilities give semantically equivalent
   results but might have hugely different execution costs.  Therefore,
   the planner will explore all of them to try to find the most
   efficient query plan.
  </P
><P
>   When a query only involves two or three tables, there aren't many join
   orders to worry about.  But the number of possible join orders grows
   exponentially as the number of tables expands.  Beyond ten or so input
   tables it's no longer practical to do an exhaustive search of all the
   possibilities, and even for six or seven tables planning might take an
   annoyingly long time.  When there are too many input tables, the
   <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> planner will switch from exhaustive
   search to a <I
CLASS="FIRSTTERM"
>genetic</I
> probabilistic search
   through a limited number of possibilities.  (The switch-over threshold is
   set by the <A
HREF="runtime-config-query.html#GUC-GEQO-THRESHOLD"
>geqo_threshold</A
> run-time
   parameter.)
   The genetic search takes less time, but it won't
   necessarily find the best possible plan.
  </P
><P
>   When the query involves outer joins, the planner has less freedom
   than it does for plain (inner) joins. For example, consider:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM a LEFT JOIN (b JOIN c ON (b.ref = c.id)) ON (a.id = b.id);</PRE
><P>
   Although this query's restrictions are superficially similar to the
   previous example, the semantics are different because a row must be
   emitted for each row of A that has no matching row in the join of B and C.
   Therefore the planner has no choice of join order here: it must join
   B to C and then join A to that result.  Accordingly, this query takes
   less time to plan than the previous query.  In other cases, the planner
   might be able to determine that more than one join order is safe.
   For example, given:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM a LEFT JOIN b ON (a.bid = b.id) LEFT JOIN c ON (a.cid = c.id);</PRE
><P>
   it is valid to join A to either B or C first.  Currently, only
   <TT
CLASS="LITERAL"
>FULL JOIN</TT
> completely constrains the join order.  Most
   practical cases involving <TT
CLASS="LITERAL"
>LEFT JOIN</TT
> or <TT
CLASS="LITERAL"
>RIGHT JOIN</TT
>
   can be rearranged to some extent.
  </P
><P
>   Explicit inner join syntax (<TT
CLASS="LITERAL"
>INNER JOIN</TT
>, <TT
CLASS="LITERAL"
>CROSS
   JOIN</TT
>, or unadorned <TT
CLASS="LITERAL"
>JOIN</TT
>) is semantically the same as
   listing the input relations in <TT
CLASS="LITERAL"
>FROM</TT
>, so it does not
   constrain the join order.
  </P
><P
>   Even though most kinds of <TT
CLASS="LITERAL"
>JOIN</TT
> don't completely constrain
   the join order, it is possible to instruct the
   <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> query planner to treat all
   <TT
CLASS="LITERAL"
>JOIN</TT
> clauses as constraining the join order anyway.
   For example, these three queries are logically equivalent:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM a, b, c WHERE a.id = b.id AND b.ref = c.id;
SELECT * FROM a CROSS JOIN b CROSS JOIN c WHERE a.id = b.id AND b.ref = c.id;
SELECT * FROM a JOIN (b JOIN c ON (b.ref = c.id)) ON (a.id = b.id);</PRE
><P>
   But if we tell the planner to honor the <TT
CLASS="LITERAL"
>JOIN</TT
> order,
   the second and third take less time to plan than the first.  This effect
   is not worth worrying about for only three tables, but it can be a
   lifesaver with many tables.
  </P
><P
>   To force the planner to follow the join order laid out by explicit
   <TT
CLASS="LITERAL"
>JOIN</TT
>s,
   set the <A
HREF="runtime-config-query.html#GUC-JOIN-COLLAPSE-LIMIT"
>join_collapse_limit</A
> run-time parameter to 1.
   (Other possible values are discussed below.)
  </P
><P
>   You do not need to constrain the join order completely in order to
   cut search time, because it's OK to use <TT
CLASS="LITERAL"
>JOIN</TT
> operators
   within items of a plain <TT
CLASS="LITERAL"
>FROM</TT
> list.  For example, consider:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM a CROSS JOIN b, c, d, e WHERE ...;</PRE
><P>
   With <TT
CLASS="VARNAME"
>join_collapse_limit</TT
> = 1, this
   forces the planner to join A to B before joining them to other tables,
   but doesn't constrain its choices otherwise.  In this example, the
   number of possible join orders is reduced by a factor of 5.
  </P
><P
>   Constraining the planner's search in this way is a useful technique
   both for reducing planning time and for directing the planner to a
   good query plan.  If the planner chooses a bad join order by default,
   you can force it to choose a better order via <TT
CLASS="LITERAL"
>JOIN</TT
> syntax
   &mdash; assuming that you know of a better order, that is.  Experimentation
   is recommended.
  </P
><P
>   A closely related issue that affects planning time is collapsing of
   subqueries into their parent query.  For example, consider:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT *
FROM x, y,
    (SELECT * FROM a, b, c WHERE something) AS ss
WHERE somethingelse;</PRE
><P>
   This situation might arise from use of a view that contains a join;
   the view's <TT
CLASS="LITERAL"
>SELECT</TT
> rule will be inserted in place of the view
   reference, yielding a query much like the above.  Normally, the planner
   will try to collapse the subquery into the parent, yielding:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM x, y, a, b, c WHERE something AND somethingelse;</PRE
><P>
   This usually results in a better plan than planning the subquery
   separately.  (For example, the outer <TT
CLASS="LITERAL"
>WHERE</TT
> conditions might be such that
   joining X to A first eliminates many rows of A, thus avoiding the need to
   form the full logical output of the subquery.)  But at the same time,
   we have increased the planning time; here, we have a five-way join
   problem replacing two separate three-way join problems.  Because of the
   exponential growth of the number of possibilities, this makes a big
   difference.  The planner tries to avoid getting stuck in huge join search
   problems by not collapsing a subquery if more than <TT
CLASS="VARNAME"
>from_collapse_limit</TT
>
   <TT
CLASS="LITERAL"
>FROM</TT
> items would result in the parent
   query.  You can trade off planning time against quality of plan by
   adjusting this run-time parameter up or down.
  </P
><P
>   <A
HREF="runtime-config-query.html#GUC-FROM-COLLAPSE-LIMIT"
>from_collapse_limit</A
> and <A
HREF="runtime-config-query.html#GUC-JOIN-COLLAPSE-LIMIT"
>join_collapse_limit</A
>
   are similarly named because they do almost the same thing: one controls
   when the planner will <SPAN
CLASS="QUOTE"
>"flatten out"</SPAN
> subqueries, and the
   other controls when it will flatten out explicit joins.  Typically
   you would either set <TT
CLASS="VARNAME"
>join_collapse_limit</TT
> equal to
   <TT
CLASS="VARNAME"
>from_collapse_limit</TT
> (so that explicit joins and subqueries
   act similarly) or set <TT
CLASS="VARNAME"
>join_collapse_limit</TT
> to 1 (if you want
   to control join order with explicit joins).  But you might set them
   differently if you are trying to fine-tune the trade-off between planning
   time and run time.
  </P
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="planner-stats.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="populate.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Statistics Used by the Planner</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="performance-tips.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Populating a Database</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>