1 <!-- doc/src/sgml/perform.sgml -->
3 <chapter id=
"performance-tips">
4 <title>Performance Tips
</title>
6 <indexterm zone=
"performance-tips">
7 <primary>performance
</primary>
11 Query performance can be affected by many things. Some of these can
12 be controlled by the user, while others are fundamental to the underlying
13 design of the system. This chapter provides some hints about understanding
14 and tuning
<productname>PostgreSQL
</productname> performance.
17 <sect1 id=
"using-explain">
18 <title>Using
<command>EXPLAIN
</command></title>
20 <indexterm zone=
"using-explain">
21 <primary>EXPLAIN
</primary>
24 <indexterm zone=
"using-explain">
25 <primary>query plan
</primary>
29 <productname>PostgreSQL
</productname> devises a
<firstterm>query
30 plan
</firstterm> for each query it receives. Choosing the right
31 plan to match the query structure and the properties of the data
32 is absolutely critical for good performance, so the system includes
33 a complex
<firstterm>planner
</firstterm> that tries to choose good plans.
34 You can use the
<link linkend=
"sql-explain"><command>EXPLAIN
</command></link> command
35 to see what query plan the planner creates for any query.
36 Plan-reading is an art that requires some experience to master,
37 but this section attempts to cover the basics.
41 Examples in this section are drawn from the regression test database
42 after doing a
<command>VACUUM ANALYZE
</command>, using v18 development sources.
43 You should be able to get similar results if you try the examples
44 yourself, but your estimated costs and row counts might vary slightly
45 because
<command>ANALYZE
</command>'s statistics are random samples rather
46 than exact, and because costs are inherently somewhat platform-dependent.
50 The examples use
<command>EXPLAIN
</command>'s default
<quote>text
</quote> output
51 format, which is compact and convenient for humans to read.
52 If you want to feed
<command>EXPLAIN
</command>'s output to a program for further
53 analysis, you should use one of its machine-readable output formats
54 (XML, JSON, or YAML) instead.
57 <sect2 id=
"using-explain-basics">
58 <title><command>EXPLAIN
</command> Basics
</title>
61 The structure of a query plan is a tree of
<firstterm>plan nodes
</firstterm>.
62 Nodes at the bottom level of the tree are scan nodes: they return raw rows
63 from a table. There are different types of scan nodes for different
64 table access methods: sequential scans, index scans, and bitmap index
65 scans. There are also non-table row sources, such as
<literal>VALUES
</literal>
66 clauses and set-returning functions in
<literal>FROM
</literal>, which have their
68 If the query requires joining, aggregation, sorting, or other
69 operations on the raw rows, then there will be additional nodes
70 above the scan nodes to perform these operations. Again,
71 there is usually more than one possible way to do these operations,
72 so different node types can appear here too. The output
73 of
<command>EXPLAIN
</command> has one line for each node in the plan
74 tree, showing the basic node type plus the cost estimates that the planner
75 made for the execution of that plan node. Additional lines might appear,
76 indented from the node's summary line,
77 to show additional properties of the node.
78 The very first line (the summary line for the topmost
79 node) has the estimated total execution cost for the plan; it is this
80 number that the planner seeks to minimize.
84 Here is a trivial example, just to show what the output looks like:
87 EXPLAIN SELECT * FROM tenk1;
90 -------------------------------------------------------------
91 Seq Scan on tenk1 (cost=
0.00.
.445.00 rows=
10000 width=
244)
96 Since this query has no
<literal>WHERE
</literal> clause, it must scan all the
97 rows of the table, so the planner has chosen to use a simple sequential
98 scan plan. The numbers that are quoted in parentheses are (left
104 Estimated start-up cost. This is the time expended before the output
105 phase can begin, e.g., time to do the sorting in a sort node.
111 Estimated total cost. This is stated on the assumption that the plan
112 node is run to completion, i.e., all available rows are retrieved.
113 In practice a node's parent node might stop short of reading all
114 available rows (see the
<literal>LIMIT
</literal> example below).
120 Estimated number of rows output by this plan node. Again, the node
121 is assumed to be run to completion.
127 Estimated average width of rows output by this plan node (in bytes).
134 The costs are measured in arbitrary units determined by the planner's
135 cost parameters (see
<xref linkend=
"runtime-config-query-constants"/>).
136 Traditional practice is to measure the costs in units of disk page
137 fetches; that is,
<xref linkend=
"guc-seq-page-cost"/> is conventionally
138 set to
<literal>1.0</literal> and the other cost parameters are set relative
139 to that. The examples in this section are run with the default cost
144 It's important to understand that the cost of an upper-level node includes
145 the cost of all its child nodes. It's also important to realize that
146 the cost only reflects things that the planner cares about.
147 In particular, the cost does not consider the time spent to convert
148 output values to text form or to transmit them to the client, which
149 could be important factors in the real elapsed time; but the planner
150 ignores those costs because it cannot change them by altering the
151 plan. (Every correct plan will output the same row set, we trust.)
155 The
<literal>rows
</literal> value is a little tricky because it is
156 not the number of rows processed or scanned by the
157 plan node, but rather the number emitted by the node. This is often
158 less than the number scanned, as a result of filtering by any
159 <literal>WHERE
</literal>-clause conditions that are being applied at the node.
160 Ideally the top-level rows estimate will approximate the number of rows
161 actually returned, updated, or deleted by the query.
165 Returning to our example:
168 EXPLAIN SELECT * FROM tenk1;
171 -------------------------------------------------------------
172 Seq Scan on tenk1 (cost=
0.00.
.445.00 rows=
10000 width=
244)
177 These numbers are derived very straightforwardly. If you do:
180 SELECT relpages, reltuples FROM pg_class WHERE relname = 'tenk1';
183 you will find that
<classname>tenk1
</classname> has
345 disk
184 pages and
10000 rows. The estimated cost is computed as (disk pages read *
185 <xref linkend=
"guc-seq-page-cost"/>) + (rows scanned *
186 <xref linkend=
"guc-cpu-tuple-cost"/>). By default,
187 <varname>seq_page_cost
</varname> is
1.0 and
<varname>cpu_tuple_cost
</varname> is
0.01,
188 so the estimated cost is (
345 *
1.0) + (
10000 *
0.01) =
445.
192 Now let's modify the query to add a
<literal>WHERE
</literal> condition:
195 EXPLAIN SELECT * FROM tenk1 WHERE unique1
< 7000;
198 ------------------------------------------------------------
199 Seq Scan on tenk1 (cost=
0.00.
.470.00 rows=
7000 width=
244)
200 Filter: (unique1
< 7000)
203 Notice that the
<command>EXPLAIN
</command> output shows the
<literal>WHERE
</literal>
204 clause being applied as a
<quote>filter
</quote> condition attached to the Seq
205 Scan plan node. This means that
206 the plan node checks the condition for each row it scans, and outputs
207 only the ones that pass the condition.
208 The estimate of output rows has been reduced because of the
209 <literal>WHERE
</literal> clause.
210 However, the scan will still have to visit all
10000 rows, so the cost
211 hasn't decreased; in fact it has gone up a bit (by
10000 *
<xref
212 linkend=
"guc-cpu-operator-cost"/>, to be exact) to reflect the extra CPU
213 time spent checking the
<literal>WHERE
</literal> condition.
217 The actual number of rows this query would select is
7000, but the
<literal>rows
</literal>
218 estimate is only approximate. If you try to duplicate this experiment,
219 you may well get a slightly different estimate; moreover, it can
220 change after each
<command>ANALYZE
</command> command, because the
221 statistics produced by
<command>ANALYZE
</command> are taken from a
222 randomized sample of the table.
226 Now, let's make the condition more restrictive:
229 EXPLAIN SELECT * FROM tenk1 WHERE unique1
< 100;
232 -------------------------------------------------------------------
&zwsp;-----------
233 Bitmap Heap Scan on tenk1 (cost=
5.06.
.224.98 rows=
100 width=
244)
234 Recheck Cond: (unique1
< 100)
235 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0)
236 Index Cond: (unique1
< 100)
239 Here the planner has decided to use a two-step plan: the child plan
240 node visits an index to find the locations of rows matching the index
241 condition, and then the upper plan node actually fetches those rows
242 from the table itself. Fetching rows separately is much more
243 expensive than reading them sequentially, but because not all the pages
244 of the table have to be visited, this is still cheaper than a sequential
245 scan. (The reason for using two plan levels is that the upper plan
246 node sorts the row locations identified by the index into physical order
247 before reading them, to minimize the cost of separate fetches.
248 The
<quote>bitmap
</quote> mentioned in the node names is the mechanism that
253 Now let's add another condition to the
<literal>WHERE
</literal> clause:
256 EXPLAIN SELECT * FROM tenk1 WHERE unique1
< 100 AND stringu1 = 'xxx';
259 -------------------------------------------------------------------
&zwsp;-----------
260 Bitmap Heap Scan on tenk1 (cost=
5.04.
.225.20 rows=
1 width=
244)
261 Recheck Cond: (unique1
< 100)
262 Filter: (stringu1 = 'xxx'::name)
263 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0)
264 Index Cond: (unique1
< 100)
267 The added condition
<literal>stringu1 = 'xxx'
</literal> reduces the
268 output row count estimate, but not the cost because we still have to visit
269 the same set of rows. That's because the
<literal>stringu1
</literal> clause
270 cannot be applied as an index condition, since this index is only on
271 the
<literal>unique1
</literal> column. Instead it is applied as a filter on
272 the rows retrieved using the index. Thus the cost has actually gone up
273 slightly to reflect this extra checking.
277 In some cases the planner will prefer a
<quote>simple
</quote> index scan plan:
280 EXPLAIN SELECT * FROM tenk1 WHERE unique1 =
42;
283 -------------------------------------------------------------------
&zwsp;----------
284 Index Scan using tenk1_unique1 on tenk1 (cost=
0.29.
.8.30 rows=
1 width=
244)
285 Index Cond: (unique1 =
42)
288 In this type of plan the table rows are fetched in index order, which
289 makes them even more expensive to read, but there are so few that the
290 extra cost of sorting the row locations is not worth it. You'll most
291 often see this plan type for queries that fetch just a single row. It's
292 also often used for queries that have an
<literal>ORDER BY
</literal> condition
293 that matches the index order, because then no extra sorting step is needed
294 to satisfy the
<literal>ORDER BY
</literal>. In this example, adding
295 <literal>ORDER BY unique1
</literal> would use the same plan because the
296 index already implicitly provides the requested ordering.
300 The planner may implement an
<literal>ORDER BY
</literal> clause in several
301 ways. The above example shows that such an ordering clause may be
302 implemented implicitly. The planner may also add an explicit
303 <literal>Sort
</literal> step:
306 EXPLAIN SELECT * FROM tenk1 ORDER BY unique1;
309 -------------------------------------------------------------------
310 Sort (cost=
1109.39.
.1134.39 rows=
10000 width=
244)
312 -
> Seq Scan on tenk1 (cost=
0.00.
.445.00 rows=
10000 width=
244)
315 If a part of the plan guarantees an ordering on a prefix of the
316 required sort keys, then the planner may instead decide to use an
317 <literal>Incremental Sort
</literal> step:
320 EXPLAIN SELECT * FROM tenk1 ORDER BY hundred, ten LIMIT
100;
323 -------------------------------------------------------------------
&zwsp;-----------------------------
324 Limit (cost=
19.35.
.39.49 rows=
100 width=
244)
325 -
> Incremental Sort (cost=
19.35.
.2033.39 rows=
10000 width=
244)
326 Sort Key: hundred, ten
327 Presorted Key: hundred
328 -
> Index Scan using tenk1_hundred on tenk1 (cost=
0.29.
.1574.20 rows=
10000 width=
244)
331 Compared to regular sorts, sorting incrementally allows returning tuples
332 before the entire result set has been sorted, which particularly enables
333 optimizations with
<literal>LIMIT
</literal> queries. It may also reduce
334 memory usage and the likelihood of spilling sorts to disk, but it comes at
335 the cost of the increased overhead of splitting the result set into multiple
340 If there are separate indexes on several of the columns referenced
341 in
<literal>WHERE
</literal>, the planner might choose to use an AND or OR
342 combination of the indexes:
345 EXPLAIN SELECT * FROM tenk1 WHERE unique1
< 100 AND unique2
> 9000;
348 -------------------------------------------------------------------
&zwsp;------------------
349 Bitmap Heap Scan on tenk1 (cost=
25.07.
.60.11 rows=
10 width=
244)
350 Recheck Cond: ((unique1
< 100) AND (unique2
> 9000))
351 -
> BitmapAnd (cost=
25.07.
.25.07 rows=
10 width=
0)
352 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0)
353 Index Cond: (unique1
< 100)
354 -
> Bitmap Index Scan on tenk1_unique2 (cost=
0.00.
.19.78 rows=
999 width=
0)
355 Index Cond: (unique2
> 9000)
358 But this requires visiting both indexes, so it's not necessarily a win
359 compared to using just one index and treating the other condition as
360 a filter. If you vary the ranges involved you'll see the plan change
365 Here is an example showing the effects of
<literal>LIMIT
</literal>:
368 EXPLAIN SELECT * FROM tenk1 WHERE unique1
< 100 AND unique2
> 9000 LIMIT
2;
371 -------------------------------------------------------------------
&zwsp;------------------
372 Limit (cost=
0.29.
.14.28 rows=
2 width=
244)
373 -
> Index Scan using tenk1_unique2 on tenk1 (cost=
0.29.
.70.27 rows=
10 width=
244)
374 Index Cond: (unique2
> 9000)
375 Filter: (unique1
< 100)
380 This is the same query as above, but we added a
<literal>LIMIT
</literal> so that
381 not all the rows need be retrieved, and the planner changed its mind about
382 what to do. Notice that the total cost and row count of the Index Scan
383 node are shown as if it were run to completion. However, the Limit node
384 is expected to stop after retrieving only a fifth of those rows, so its
385 total cost is only a fifth as much, and that's the actual estimated cost
386 of the query. This plan is preferred over adding a Limit node to the
387 previous plan because the Limit could not avoid paying the startup cost
388 of the bitmap scan, so the total cost would be something over
25 units
393 Let's try joining two tables, using the columns we have been discussing:
397 FROM tenk1 t1, tenk2 t2
398 WHERE t1.unique1
< 10 AND t1.unique2 = t2.unique2;
401 -------------------------------------------------------------------
&zwsp;-------------------
402 Nested Loop (cost=
4.65.
.118.50 rows=
10 width=
488)
403 -
> Bitmap Heap Scan on tenk1 t1 (cost=
4.36.
.39.38 rows=
10 width=
244)
404 Recheck Cond: (unique1
< 10)
405 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.4.36 rows=
10 width=
0)
406 Index Cond: (unique1
< 10)
407 -
> Index Scan using tenk2_unique2 on tenk2 t2 (cost=
0.29.
.7.90 rows=
1 width=
244)
408 Index Cond: (unique2 = t1.unique2)
413 In this plan, we have a nested-loop join node with two table scans as
414 inputs, or children. The indentation of the node summary lines reflects
415 the plan tree structure. The join's first, or
<quote>outer
</quote>, child
416 is a bitmap scan similar to those we saw before. Its cost and row count
417 are the same as we'd get from
<literal>SELECT ... WHERE unique1
< 10</literal>
419 applying the
<literal>WHERE
</literal> clause
<literal>unique1
< 10</literal>
421 The
<literal>t1.unique2 = t2.unique2
</literal> clause is not relevant yet,
422 so it doesn't affect the row count of the outer scan. The nested-loop
423 join node will run its second,
424 or
<quote>inner
</quote> child once for each row obtained from the outer child.
425 Column values from the current outer row can be plugged into the inner
426 scan; here, the
<literal>t1.unique2
</literal> value from the outer row is available,
427 so we get a plan and costs similar to what we saw above for a simple
428 <literal>SELECT ... WHERE t2.unique2 =
<replaceable>constant
</replaceable></literal> case.
429 (The estimated cost is actually a bit lower than what was seen above,
430 as a result of caching that's expected to occur during the repeated
431 index scans on
<literal>t2
</literal>.) The
432 costs of the loop node are then set on the basis of the cost of the outer
433 scan, plus one repetition of the inner scan for each outer row (
10 *
7.90,
434 here), plus a little CPU time for join processing.
438 In this example the join's output row count is the same as the product
439 of the two scans' row counts, but that's not true in all cases because
440 there can be additional
<literal>WHERE
</literal> clauses that mention both tables
441 and so can only be applied at the join point, not to either input scan.
446 FROM tenk1 t1, tenk2 t2
447 WHERE t1.unique1
< 10 AND t2.unique2
< 10 AND t1.hundred
< t2.hundred;
450 -------------------------------------------------------------------
&zwsp;--------------------------
451 Nested Loop (cost=
4.65.
.49.36 rows=
33 width=
488)
452 Join Filter: (t1.hundred
< t2.hundred)
453 -
> Bitmap Heap Scan on tenk1 t1 (cost=
4.36.
.39.38 rows=
10 width=
244)
454 Recheck Cond: (unique1
< 10)
455 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.4.36 rows=
10 width=
0)
456 Index Cond: (unique1
< 10)
457 -
> Materialize (cost=
0.29.
.8.51 rows=
10 width=
244)
458 -
> Index Scan using tenk2_unique2 on tenk2 t2 (cost=
0.29.
.8.46 rows=
10 width=
244)
459 Index Cond: (unique2
< 10)
462 The condition
<literal>t1.hundred
< t2.hundred
</literal> can't be
463 tested in the
<literal>tenk2_unique2
</literal> index, so it's applied at the
464 join node. This reduces the estimated output row count of the join node,
465 but does not change either input scan.
469 Notice that here the planner has chosen to
<quote>materialize
</quote> the inner
470 relation of the join, by putting a Materialize plan node atop it. This
471 means that the
<literal>t2
</literal> index scan will be done just once, even
472 though the nested-loop join node needs to read that data ten times, once
473 for each row from the outer relation. The Materialize node saves the data
474 in memory as it's read, and then returns the data from memory on each
479 When dealing with outer joins, you might see join plan nodes with both
480 <quote>Join Filter
</quote> and plain
<quote>Filter
</quote> conditions attached.
481 Join Filter conditions come from the outer join's
<literal>ON
</literal> clause,
482 so a row that fails the Join Filter condition could still get emitted as
483 a null-extended row. But a plain Filter condition is applied after the
484 outer-join rules and so acts to remove rows unconditionally. In an inner
485 join there is no semantic difference between these types of filters.
489 If we change the query's selectivity a bit, we might get a very different
494 FROM tenk1 t1, tenk2 t2
495 WHERE t1.unique1
< 100 AND t1.unique2 = t2.unique2;
498 -------------------------------------------------------------------
&zwsp;-----------------------
499 Hash Join (cost=
226.23.
.709.73 rows=
100 width=
488)
500 Hash Cond: (t2.unique2 = t1.unique2)
501 -
> Seq Scan on tenk2 t2 (cost=
0.00.
.445.00 rows=
10000 width=
244)
502 -
> Hash (cost=
224.98.
.224.98 rows=
100 width=
244)
503 -
> Bitmap Heap Scan on tenk1 t1 (cost=
5.06.
.224.98 rows=
100 width=
244)
504 Recheck Cond: (unique1
< 100)
505 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0)
506 Index Cond: (unique1
< 100)
511 Here, the planner has chosen to use a hash join, in which rows of one
512 table are entered into an in-memory hash table, after which the other
513 table is scanned and the hash table is probed for matches to each row.
514 Again note how the indentation reflects the plan structure: the bitmap
515 scan on
<literal>tenk1
</literal> is the input to the Hash node, which constructs
516 the hash table. That's then returned to the Hash Join node, which reads
517 rows from its outer child plan and searches the hash table for each one.
521 Another possible type of join is a merge join, illustrated here:
525 FROM tenk1 t1, onek t2
526 WHERE t1.unique1
< 100 AND t1.unique2 = t2.unique2;
529 -------------------------------------------------------------------
&zwsp;-----------------------
530 Merge Join (cost=
0.56.
.233.49 rows=
10 width=
488)
531 Merge Cond: (t1.unique2 = t2.unique2)
532 -
> Index Scan using tenk1_unique2 on tenk1 t1 (cost=
0.29.
.643.28 rows=
100 width=
244)
533 Filter: (unique1
< 100)
534 -
> Index Scan using onek_unique2 on onek t2 (cost=
0.28.
.166.28 rows=
1000 width=
244)
539 Merge join requires its input data to be sorted on the join keys. In this
540 example each input is sorted by using an index scan to visit the rows
541 in the correct order; but a sequential scan and sort could also be used.
542 (Sequential-scan-and-sort frequently beats an index scan for sorting many rows,
543 because of the nonsequential disk access required by the index scan.)
547 One way to look at variant plans is to force the planner to disregard
548 whatever strategy it thought was the cheapest, using the enable/disable
549 flags described in
<xref linkend=
"runtime-config-query-enable"/>.
550 (This is a crude tool, but useful. See
551 also
<xref linkend=
"explicit-joins"/>.)
552 For example, if we're unconvinced that merge join is the best join
553 type for the previous example, we could try
556 SET enable_mergejoin = off;
559 FROM tenk1 t1, onek t2
560 WHERE t1.unique1
< 100 AND t1.unique2 = t2.unique2;
563 -------------------------------------------------------------------
&zwsp;-----------------------
564 Hash Join (cost=
226.23.
.344.08 rows=
10 width=
488)
565 Hash Cond: (t2.unique2 = t1.unique2)
566 -
> Seq Scan on onek t2 (cost=
0.00.
.114.00 rows=
1000 width=
244)
567 -
> Hash (cost=
224.98.
.224.98 rows=
100 width=
244)
568 -
> Bitmap Heap Scan on tenk1 t1 (cost=
5.06.
.224.98 rows=
100 width=
244)
569 Recheck Cond: (unique1
< 100)
570 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0)
571 Index Cond: (unique1
< 100)
574 which shows that the planner thinks that hash join would be nearly
50%
575 more expensive than merge join for this case.
576 Of course, the next question is whether it's right about that.
577 We can investigate that using
<command>EXPLAIN ANALYZE
</command>, as
578 discussed
<link linkend=
"using-explain-analyze">below
</link>.
582 When using the enable/disable flags to disable plan node types, many of
583 the flags only discourage the use of the corresponding plan node and don't
584 outright disallow the planner's ability to use the plan node type. This
585 is by design so that the planner still maintains the ability to form a
586 plan for a given query. When the resulting plan contains a disabled node,
587 the
<command>EXPLAIN
</command> output will indicate this fact.
590 SET enable_seqscan = off;
591 EXPLAIN SELECT * FROM unit;
594 ---------------------------------------------------------
595 Seq Scan on unit (cost=
0.00.
.21.30 rows=
1130 width=
44)
601 Because the
<literal>unit
</literal> table has no indexes, there is no
602 other means to read the table data, so the sequential scan is the only
603 option available to the query planner.
608 <primary>subplan
</primary>
610 Some query plans involve
<firstterm>subplans
</firstterm>, which arise
611 from sub-
<literal>SELECT
</literal>s in the original query. Such
612 queries can sometimes be transformed into ordinary join plans, but
613 when they cannot be, we get plans like:
616 EXPLAIN VERBOSE SELECT unique1
618 WHERE t.ten
< ALL (SELECT o.ten FROM onek o WHERE o.four = t.four);
621 -------------------------------------------------------------------
&zwsp;------
622 Seq Scan on public.tenk1 t (cost=
0.00.
.586095.00 rows=
5000 width=
4)
624 Filter: (ALL (t.ten
< (SubPlan
1).col1))
626 -
> Seq Scan on public.onek o (cost=
0.00.
.116.50 rows=
250 width=
4)
628 Filter: (o.four = t.four)
631 This rather artificial example serves to illustrate a couple of
632 points: values from the outer plan level can be passed down into a
633 subplan (here,
<literal>t.four
</literal> is passed down) and the
634 results of the sub-select are available to the outer plan. Those
635 result values are shown by
<command>EXPLAIN
</command> with notations
637 <literal>(
<replaceable>subplan_name
</replaceable>).col
<replaceable>N
</replaceable></literal>,
638 which refers to the
<replaceable>N
</replaceable>'th output column of
639 the sub-
<literal>SELECT
</literal>.
644 <primary>subplan
</primary>
645 <secondary>hashed
</secondary>
647 In the example above, the
<literal>ALL
</literal> operator runs the
648 subplan again for each row of the outer query (which accounts for the
649 high estimated cost). Some queries can use a
<firstterm>hashed
650 subplan
</firstterm> to avoid that:
655 WHERE t.unique1 NOT IN (SELECT o.unique1 FROM onek o);
658 -------------------------------------------------------------------
&zwsp;-------------------------
659 Seq Scan on tenk1 t (cost=
61.77.
.531.77 rows=
5000 width=
244)
660 Filter: (NOT (ANY (unique1 = (hashed SubPlan
1).col1)))
662 -
> Index Only Scan using onek_unique1 on onek o (cost=
0.28.
.59.27 rows=
1000 width=
4)
666 Here, the subplan is run a single time and its output is loaded into
667 an in-memory hash table, which is then probed by the
668 outer
<literal>ANY
</literal> operator. This requires that the
669 sub-
<literal>SELECT
</literal> not reference any variables of the outer
670 query, and that the
<literal>ANY
</literal>'s comparison operator be
676 <primary>initplan
</primary>
678 If, in addition to not referencing any variables of the outer query,
679 the sub-
<literal>SELECT
</literal> cannot return more than one row,
680 it may instead be implemented as an
<firstterm>initplan
</firstterm>:
683 EXPLAIN VERBOSE SELECT unique1
684 FROM tenk1 t1 WHERE t1.ten = (SELECT (random() *
10)::integer);
687 ------------------------------------------------------------
&zwsp;--------
688 Seq Scan on public.tenk1 t1 (cost=
0.02.
.470.02 rows=
1000 width=
4)
690 Filter: (t1.ten = (InitPlan
1).col1)
692 -
> Result (cost=
0.00.
.0.02 rows=
1 width=
4)
693 Output: ((random() * '
10'::double precision))::integer
696 An initplan is run only once per execution of the outer plan, and its
697 results are saved for re-use in later rows of the outer plan. So in
698 this example
<literal>random()
</literal> is evaluated only once and
699 all the values of
<literal>t1.ten
</literal> are compared to the same
700 randomly-chosen integer. That's quite different from what would
701 happen without the sub-
<literal>SELECT
</literal> construct.
706 <sect2 id=
"using-explain-analyze">
707 <title><command>EXPLAIN ANALYZE
</command></title>
710 It is possible to check the accuracy of the planner's estimates
711 by using
<command>EXPLAIN
</command>'s
<literal>ANALYZE
</literal> option. With this
712 option,
<command>EXPLAIN
</command> actually executes the query, and then displays
713 the true row counts and true run time accumulated within each plan node,
714 along with the same estimates that a plain
<command>EXPLAIN
</command>
715 shows. For example, we might get a result like this:
718 EXPLAIN ANALYZE SELECT *
719 FROM tenk1 t1, tenk2 t2
720 WHERE t1.unique1
< 10 AND t1.unique2 = t2.unique2;
723 -------------------------------------------------------------------
&zwsp;--------------------------------------------------------------
724 Nested Loop (cost=
4.65.
.118.50 rows=
10 width=
488) (actual time=
0.017.
.0.051 rows=
10 loops=
1)
725 Buffers: shared hit=
36 read=
6
726 -
> Bitmap Heap Scan on tenk1 t1 (cost=
4.36.
.39.38 rows=
10 width=
244) (actual time=
0.009.
.0.017 rows=
10 loops=
1)
727 Recheck Cond: (unique1
< 10)
728 Heap Blocks: exact=
10
729 Buffers: shared hit=
3 read=
5 written=
4
730 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.4.36 rows=
10 width=
0) (actual time=
0.004.
.0.004 rows=
10 loops=
1)
731 Index Cond: (unique1
< 10)
732 Buffers: shared hit=
2
733 -
> Index Scan using tenk2_unique2 on tenk2 t2 (cost=
0.29.
.7.90 rows=
1 width=
244) (actual time=
0.003.
.0.003 rows=
1 loops=
10)
734 Index Cond: (unique2 = t1.unique2)
735 Buffers: shared hit=
24 read=
6
737 Buffers: shared hit=
15 dirtied=
9
738 Planning Time:
0.485 ms
739 Execution Time:
0.073 ms
742 Note that the
<quote>actual time
</quote> values are in milliseconds of
743 real time, whereas the
<literal>cost
</literal> estimates are expressed in
744 arbitrary units; so they are unlikely to match up.
745 The thing that's usually most important to look for is whether the
746 estimated row counts are reasonably close to reality. In this example
747 the estimates were all dead-on, but that's quite unusual in practice.
751 In some query plans, it is possible for a subplan node to be executed more
752 than once. For example, the inner index scan will be executed once per
753 outer row in the above nested-loop plan. In such cases, the
754 <literal>loops
</literal> value reports the
755 total number of executions of the node, and the actual time and rows
756 values shown are averages per-execution. This is done to make the numbers
757 comparable with the way that the cost estimates are shown. Multiply by
758 the
<literal>loops
</literal> value to get the total time actually spent in
759 the node. In the above example, we spent a total of
0.030 milliseconds
760 executing the index scans on
<literal>tenk2
</literal>.
764 In some cases
<command>EXPLAIN ANALYZE
</command> shows additional execution
765 statistics beyond the plan node execution times and row counts.
766 For example, Sort and Hash nodes provide extra information:
769 EXPLAIN ANALYZE SELECT *
770 FROM tenk1 t1, tenk2 t2
771 WHERE t1.unique1
< 100 AND t1.unique2 = t2.unique2 ORDER BY t1.fivethous;
774 -------------------------------------------------------------------
&zwsp;-------------------------------------------------------------------
&zwsp;------
775 Sort (cost=
713.05.
.713.30 rows=
100 width=
488) (actual time=
2.995.
.3.002 rows=
100 loops=
1)
776 Sort Key: t1.fivethous
777 Sort Method: quicksort Memory:
74kB
778 Buffers: shared hit=
440
779 -
> Hash Join (cost=
226.23.
.709.73 rows=
100 width=
488) (actual time=
0.515.
.2.920 rows=
100 loops=
1)
780 Hash Cond: (t2.unique2 = t1.unique2)
781 Buffers: shared hit=
437
782 -
> Seq Scan on tenk2 t2 (cost=
0.00.
.445.00 rows=
10000 width=
244) (actual time=
0.026.
.1.790 rows=
10000 loops=
1)
783 Buffers: shared hit=
345
784 -
> Hash (cost=
224.98.
.224.98 rows=
100 width=
244) (actual time=
0.476.
.0.477 rows=
100 loops=
1)
785 Buckets:
1024 Batches:
1 Memory Usage:
35kB
786 Buffers: shared hit=
92
787 -
> Bitmap Heap Scan on tenk1 t1 (cost=
5.06.
.224.98 rows=
100 width=
244) (actual time=
0.030.
.0.450 rows=
100 loops=
1)
788 Recheck Cond: (unique1
< 100)
789 Heap Blocks: exact=
90
790 Buffers: shared hit=
92
791 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0) (actual time=
0.013.
.0.013 rows=
100 loops=
1)
792 Index Cond: (unique1
< 100)
793 Buffers: shared hit=
2
795 Buffers: shared hit=
12
796 Planning Time:
0.187 ms
797 Execution Time:
3.036 ms
800 The Sort node shows the sort method used (in particular, whether the sort
801 was in-memory or on-disk) and the amount of memory or disk space needed.
802 The Hash node shows the number of hash buckets and batches as well as the
803 peak amount of memory used for the hash table. (If the number of batches
804 exceeds one, there will also be disk space usage involved, but that is not
809 Another type of extra information is the number of rows removed by a
813 EXPLAIN ANALYZE SELECT * FROM tenk1 WHERE ten
< 7;
816 -------------------------------------------------------------------
&zwsp;--------------------------------------
817 Seq Scan on tenk1 (cost=
0.00.
.470.00 rows=
7000 width=
244) (actual time=
0.030.
.1.995 rows=
7000 loops=
1)
819 Rows Removed by Filter:
3000
820 Buffers: shared hit=
345
821 Planning Time:
0.102 ms
822 Execution Time:
2.145 ms
825 These counts can be particularly valuable for filter conditions applied at
826 join nodes. The
<quote>Rows Removed
</quote> line only appears when at least
827 one scanned row, or potential join pair in the case of a join node,
828 is rejected by the filter condition.
832 A case similar to filter conditions occurs with
<quote>lossy
</quote>
833 index scans. For example, consider this search for polygons containing a
837 EXPLAIN ANALYZE SELECT * FROM polygon_tbl WHERE f1 @
> polygon '(
0.5,
2.0)';
840 -------------------------------------------------------------------
&zwsp;-----------------------------------
841 Seq Scan on polygon_tbl (cost=
0.00.
.1.09 rows=
1 width=
85) (actual time=
0.023.
.0.023 rows=
0 loops=
1)
842 Filter: (f1 @
> '((
0.5,
2))'::polygon)
843 Rows Removed by Filter:
7
844 Buffers: shared hit=
1
845 Planning Time:
0.039 ms
846 Execution Time:
0.033 ms
849 The planner thinks (quite correctly) that this sample table is too small
850 to bother with an index scan, so we have a plain sequential scan in which
851 all the rows got rejected by the filter condition. But if we force an
852 index scan to be used, we see:
855 SET enable_seqscan TO off;
857 EXPLAIN ANALYZE SELECT * FROM polygon_tbl WHERE f1 @
> polygon '(
0.5,
2.0)';
860 -------------------------------------------------------------------
&zwsp;-------------------------------------------------------
861 Index Scan using gpolygonind on polygon_tbl (cost=
0.13.
.8.15 rows=
1 width=
85) (actual time=
0.074.
.0.074 rows=
0 loops=
1)
862 Index Cond: (f1 @
> '((
0.5,
2))'::polygon)
863 Rows Removed by Index Recheck:
1
864 Buffers: shared hit=
1
865 Planning Time:
0.039 ms
866 Execution Time:
0.098 ms
869 Here we can see that the index returned one candidate row, which was
870 then rejected by a recheck of the index condition. This happens because a
871 GiST index is
<quote>lossy
</quote> for polygon containment tests: it actually
872 returns the rows with polygons that overlap the target, and then we have
873 to do the exact containment test on those rows.
877 <command>EXPLAIN
</command> has a
<literal>BUFFERS
</literal> option which
878 provides additional detail about I/O operations performed during the
879 planning and execution of the given query. The buffer numbers displayed
880 show the count of the non-distinct buffers hit, read, dirtied, and written
881 for the given node and all of its child nodes. The
882 <literal>ANALYZE
</literal> option implicitly enables the
883 <literal>BUFFERS
</literal> option. If this
884 is undesired,
<literal>BUFFERS
</literal> may be explicitly disabled:
887 EXPLAIN (ANALYZE, BUFFERS OFF) SELECT * FROM tenk1 WHERE unique1
< 100 AND unique2
> 9000;
890 -------------------------------------------------------------------
&zwsp;--------------------------------------------------------------
891 Bitmap Heap Scan on tenk1 (cost=
25.07.
.60.11 rows=
10 width=
244) (actual time=
0.105.
.0.114 rows=
10 loops=
1)
892 Recheck Cond: ((unique1
< 100) AND (unique2
> 9000))
893 Heap Blocks: exact=
10
894 -
> BitmapAnd (cost=
25.07.
.25.07 rows=
10 width=
0) (actual time=
0.100.
.0.101 rows=
0 loops=
1)
895 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0) (actual time=
0.027.
.0.027 rows=
100 loops=
1)
896 Index Cond: (unique1
< 100)
897 -
> Bitmap Index Scan on tenk1_unique2 (cost=
0.00.
.19.78 rows=
999 width=
0) (actual time=
0.070.
.0.070 rows=
999 loops=
1)
898 Index Cond: (unique2
> 9000)
899 Planning Time:
0.162 ms
900 Execution Time:
0.143 ms
905 Keep in mind that because
<command>EXPLAIN ANALYZE
</command> actually
906 runs the query, any side-effects will happen as usual, even though
907 whatever results the query might output are discarded in favor of
908 printing the
<command>EXPLAIN
</command> data. If you want to analyze a
909 data-modifying query without changing your tables, you can
910 roll the command back afterwards, for example:
915 EXPLAIN ANALYZE UPDATE tenk1 SET hundred = hundred +
1 WHERE unique1
< 100;
918 -------------------------------------------------------------------
&zwsp;-------------------------------------------------------------
919 Update on tenk1 (cost=
5.06.
.225.23 rows=
0 width=
0) (actual time=
1.634.
.1.635 rows=
0 loops=
1)
920 -
> Bitmap Heap Scan on tenk1 (cost=
5.06.
.225.23 rows=
100 width=
10) (actual time=
0.065.
.0.141 rows=
100 loops=
1)
921 Recheck Cond: (unique1
< 100)
922 Heap Blocks: exact=
90
923 Buffers: shared hit=
4 read=
2
924 -
> Bitmap Index Scan on tenk1_unique1 (cost=
0.00.
.5.04 rows=
100 width=
0) (actual time=
0.031.
.0.031 rows=
100 loops=
1)
925 Index Cond: (unique1
< 100)
926 Buffers: shared read=
2
927 Planning Time:
0.151 ms
928 Execution Time:
1.856 ms
935 As seen in this example, when the query is an
<command>INSERT
</command>,
936 <command>UPDATE
</command>,
<command>DELETE
</command>, or
937 <command>MERGE
</command> command, the actual work of
938 applying the table changes is done by a top-level Insert, Update,
939 Delete, or Merge plan node. The plan nodes underneath this node perform
940 the work of locating the old rows and/or computing the new data.
941 So above, we see the same sort of bitmap table scan we've seen already,
942 and its output is fed to an Update node that stores the updated rows.
943 It's worth noting that although the data-modifying node can take a
944 considerable amount of run time (here, it's consuming the lion's share
945 of the time), the planner does not currently add anything to the cost
946 estimates to account for that work. That's because the work to be done is
947 the same for every correct query plan, so it doesn't affect planning
952 When an
<command>UPDATE
</command>,
<command>DELETE
</command>, or
953 <command>MERGE
</command> command affects a partitioned table or
954 inheritance hierarchy, the output might look like this:
957 EXPLAIN UPDATE gtest_parent SET f1 = CURRENT_DATE WHERE f2 =
101;
960 -------------------------------------------------------------------
&zwsp;---------------------
961 Update on gtest_parent (cost=
0.00.
.3.06 rows=
0 width=
0)
962 Update on gtest_child gtest_parent_1
963 Update on gtest_child2 gtest_parent_2
964 Update on gtest_child3 gtest_parent_3
965 -
> Append (cost=
0.00.
.3.06 rows=
3 width=
14)
966 -
> Seq Scan on gtest_child gtest_parent_1 (cost=
0.00.
.1.01 rows=
1 width=
14)
968 -
> Seq Scan on gtest_child2 gtest_parent_2 (cost=
0.00.
.1.01 rows=
1 width=
14)
970 -
> Seq Scan on gtest_child3 gtest_parent_3 (cost=
0.00.
.1.01 rows=
1 width=
14)
974 In this example the Update node needs to consider three child tables,
975 but not the originally-mentioned partitioned table (since that never
976 stores any data). So there are three input
977 scanning subplans, one per table. For clarity, the Update node is
978 annotated to show the specific target tables that will be updated, in the
979 same order as the corresponding subplans.
983 The
<literal>Planning time
</literal> shown by
<command>EXPLAIN
984 ANALYZE
</command> is the time it took to generate the query plan from the
985 parsed query and optimize it. It does not include parsing or rewriting.
989 The
<literal>Execution time
</literal> shown by
<command>EXPLAIN
990 ANALYZE
</command> includes executor start-up and shut-down time, as well
991 as the time to run any triggers that are fired, but it does not include
992 parsing, rewriting, or planning time.
993 Time spent executing
<literal>BEFORE
</literal> triggers, if any, is included in
994 the time for the related Insert, Update, or Delete node; but time
995 spent executing
<literal>AFTER
</literal> triggers is not counted there because
996 <literal>AFTER
</literal> triggers are fired after completion of the whole plan.
997 The total time spent in each trigger
998 (either
<literal>BEFORE
</literal> or
<literal>AFTER
</literal>) is also shown separately.
999 Note that deferred constraint triggers will not be executed
1000 until end of transaction and are thus not considered at all by
1001 <command>EXPLAIN ANALYZE
</command>.
1005 The time shown for the top-level node does not include any time needed
1006 to convert the query's output data into displayable form or to send it
1007 to the client. While
<command>EXPLAIN ANALYZE
</command> will never
1008 send the data to the client, it can be told to convert the query's
1009 output data to displayable form and measure the time needed for that,
1010 by specifying the
<literal>SERIALIZE
</literal> option. That time will
1011 be shown separately, and it's also included in the
1012 total
<literal>Execution time
</literal>.
1017 <sect2 id=
"using-explain-caveats">
1018 <title>Caveats
</title>
1021 There are two significant ways in which run times measured by
1022 <command>EXPLAIN ANALYZE
</command> can deviate from normal execution of
1023 the same query. First, since no output rows are delivered to the client,
1024 network transmission costs are not included. I/O conversion costs are
1025 not included either unless
<literal>SERIALIZE
</literal> is specified.
1026 Second, the measurement overhead added by
<command>EXPLAIN
1027 ANALYZE
</command> can be significant, especially on machines with slow
1028 <function>gettimeofday()
</function> operating-system calls. You can use the
1029 <xref linkend=
"pgtesttiming"/> tool to measure the overhead of timing
1034 <command>EXPLAIN
</command> results should not be extrapolated to situations
1035 much different from the one you are actually testing; for example,
1036 results on a toy-sized table cannot be assumed to apply to large tables.
1037 The planner's cost estimates are not linear and so it might choose
1038 a different plan for a larger or smaller table. An extreme example
1039 is that on a table that only occupies one disk page, you'll nearly
1040 always get a sequential scan plan whether indexes are available or not.
1041 The planner realizes that it's going to take one disk page read to
1042 process the table in any case, so there's no value in expending additional
1043 page reads to look at an index. (We saw this happening in the
1044 <literal>polygon_tbl
</literal> example above.)
1048 There are cases in which the actual and estimated values won't match up
1049 well, but nothing is really wrong. One such case occurs when
1050 plan node execution is stopped short by a
<literal>LIMIT
</literal> or similar
1051 effect. For example, in the
<literal>LIMIT
</literal> query we used before,
1054 EXPLAIN ANALYZE SELECT * FROM tenk1 WHERE unique1
< 100 AND unique2
> 9000 LIMIT
2;
1057 -------------------------------------------------------------------
&zwsp;------------------------------------------------------------
1058 Limit (cost=
0.29.
.14.33 rows=
2 width=
244) (actual time=
0.051.
.0.071 rows=
2 loops=
1)
1059 Buffers: shared hit=
16
1060 -
> Index Scan using tenk1_unique2 on tenk1 (cost=
0.29.
.70.50 rows=
10 width=
244) (actual time=
0.051.
.0.070 rows=
2 loops=
1)
1061 Index Cond: (unique2
> 9000)
1062 Filter: (unique1
< 100)
1063 Rows Removed by Filter:
287
1064 Buffers: shared hit=
16
1065 Planning Time:
0.077 ms
1066 Execution Time:
0.086 ms
1069 the estimated cost and row count for the Index Scan node are shown as
1070 though it were run to completion. But in reality the Limit node stopped
1071 requesting rows after it got two, so the actual row count is only
2 and
1072 the run time is less than the cost estimate would suggest. This is not
1073 an estimation error, only a discrepancy in the way the estimates and true
1074 values are displayed.
1078 Merge joins also have measurement artifacts that can confuse the unwary.
1079 A merge join will stop reading one input if it's exhausted the other input
1080 and the next key value in the one input is greater than the last key value
1081 of the other input; in such a case there can be no more matches and so no
1082 need to scan the rest of the first input. This results in not reading all
1083 of one child, with results like those mentioned for
<literal>LIMIT
</literal>.
1084 Also, if the outer (first) child contains rows with duplicate key values,
1085 the inner (second) child is backed up and rescanned for the portion of its
1086 rows matching that key value.
<command>EXPLAIN ANALYZE
</command> counts these
1087 repeated emissions of the same inner rows as if they were real additional
1088 rows. When there are many outer duplicates, the reported actual row count
1089 for the inner child plan node can be significantly larger than the number
1090 of rows that are actually in the inner relation.
1094 BitmapAnd and BitmapOr nodes always report their actual row counts as zero,
1095 due to implementation limitations.
1099 Normally,
<command>EXPLAIN
</command> will display every plan node
1100 created by the planner. However, there are cases where the executor
1101 can determine that certain nodes need not be executed because they
1102 cannot produce any rows, based on parameter values that were not
1103 available at planning time. (Currently this can only happen for child
1104 nodes of an Append or MergeAppend node that is scanning a partitioned
1105 table.) When this happens, those plan nodes are omitted from
1106 the
<command>EXPLAIN
</command> output and a
<literal>Subplans
1107 Removed:
<replaceable>N
</replaceable></literal> annotation appears
1114 <sect1 id=
"planner-stats">
1115 <title>Statistics Used by the Planner
</title>
1117 <indexterm zone=
"planner-stats">
1118 <primary>statistics
</primary>
1119 <secondary>of the planner
</secondary>
1122 <sect2 id=
"planner-stats-single-column">
1123 <title>Single-Column Statistics
</title>
1125 As we saw in the previous section, the query planner needs to estimate
1126 the number of rows retrieved by a query in order to make good choices
1127 of query plans. This section provides a quick look at the statistics
1128 that the system uses for these estimates.
1132 One component of the statistics is the total number of entries in
1133 each table and index, as well as the number of disk blocks occupied
1134 by each table and index. This information is kept in the table
1135 <link linkend=
"catalog-pg-class"><structname>pg_class
</structname></link>,
1136 in the columns
<structfield>reltuples
</structfield> and
1137 <structfield>relpages
</structfield>. We can look at it with
1138 queries similar to this one:
1141 SELECT relname, relkind, reltuples, relpages
1143 WHERE relname LIKE 'tenk1%';
1145 relname | relkind | reltuples | relpages
1146 ----------------------+---------+-----------+----------
1147 tenk1 | r |
10000 |
345
1148 tenk1_hundred | i |
10000 |
11
1149 tenk1_thous_tenthous | i |
10000 |
30
1150 tenk1_unique1 | i |
10000 |
30
1151 tenk1_unique2 | i |
10000 |
30
1155 Here we can see that
<structname>tenk1
</structname> contains
10000
1156 rows, as do its indexes, but the indexes are (unsurprisingly) much
1157 smaller than the table.
1161 For efficiency reasons,
<structfield>reltuples
</structfield>
1162 and
<structfield>relpages
</structfield> are not updated on-the-fly,
1163 and so they usually contain somewhat out-of-date values.
1164 They are updated by
<command>VACUUM
</command>,
<command>ANALYZE
</command>, and a
1165 few DDL commands such as
<command>CREATE INDEX
</command>. A
<command>VACUUM
</command>
1166 or
<command>ANALYZE
</command> operation that does not scan the entire table
1167 (which is commonly the case) will incrementally update the
1168 <structfield>reltuples
</structfield> count on the basis of the part
1169 of the table it did scan, resulting in an approximate value.
1170 In any case, the planner
1171 will scale the values it finds in
<structname>pg_class
</structname>
1172 to match the current physical table size, thus obtaining a closer
1177 <primary>pg_statistic
</primary>
1181 Most queries retrieve only a fraction of the rows in a table, due
1182 to
<literal>WHERE
</literal> clauses that restrict the rows to be
1183 examined. The planner thus needs to make an estimate of the
1184 <firstterm>selectivity
</firstterm> of
<literal>WHERE
</literal> clauses, that is,
1185 the fraction of rows that match each condition in the
1186 <literal>WHERE
</literal> clause. The information used for this task is
1188 <link linkend=
"catalog-pg-statistic"><structname>pg_statistic
</structname></link>
1189 system catalog. Entries in
<structname>pg_statistic
</structname>
1190 are updated by the
<command>ANALYZE
</command> and
<command>VACUUM
1191 ANALYZE
</command> commands, and are always approximate even when freshly
1196 <primary>pg_stats
</primary>
1200 Rather than look at
<structname>pg_statistic
</structname> directly,
1201 it's better to look at its view
1202 <link linkend=
"view-pg-stats"><structname>pg_stats
</structname></link>
1203 when examining the statistics manually.
<structname>pg_stats
</structname>
1204 is designed to be more easily readable. Furthermore,
1205 <structname>pg_stats
</structname> is readable by all, whereas
1206 <structname>pg_statistic
</structname> is only readable by a superuser.
1207 (This prevents unprivileged users from learning something about
1208 the contents of other people's tables from the statistics. The
1209 <structname>pg_stats
</structname> view is restricted to show only
1210 rows about tables that the current user can read.)
1211 For example, we might do:
1214 SELECT attname, inherited, n_distinct,
1215 array_to_string(most_common_vals, E'\n') as most_common_vals
1217 WHERE tablename = 'road';
1219 attname | inherited | n_distinct | most_common_vals
1220 ---------+-----------+------------+------------------------------------
1221 name | f | -
0.5681108 | I-
580 Ramp+
1229 | | | Mac Arthur Blvd+
1232 name | t | -
0.5125 | I-
580 Ramp+
1239 | | | State Hwy
13 Ramp+
1241 | | | State Hwy
24 Ramp+
1248 Note that two rows are displayed for the same column, one corresponding
1249 to the complete inheritance hierarchy starting at the
1250 <literal>road
</literal> table (
<literal>inherited
</literal>=
<literal>t
</literal>),
1251 and another one including only the
<literal>road
</literal> table itself
1252 (
<literal>inherited
</literal>=
<literal>f
</literal>).
1253 (For brevity, we have only shown the first ten most-common values for
1254 the
<literal>name
</literal> column.)
1258 The amount of information stored in
<structname>pg_statistic
</structname>
1259 by
<command>ANALYZE
</command>, in particular the maximum number of entries in the
1260 <structfield>most_common_vals
</structfield> and
<structfield>histogram_bounds
</structfield>
1261 arrays for each column, can be set on a
1262 column-by-column basis using the
<command>ALTER TABLE SET STATISTICS
</command>
1263 command, or globally by setting the
1264 <xref linkend=
"guc-default-statistics-target"/> configuration variable.
1265 The default limit is presently
100 entries. Raising the limit
1266 might allow more accurate planner estimates to be made, particularly for
1267 columns with irregular data distributions, at the price of consuming
1268 more space in
<structname>pg_statistic
</structname> and slightly more
1269 time to compute the estimates. Conversely, a lower limit might be
1270 sufficient for columns with simple data distributions.
1274 Further details about the planner's use of statistics can be found in
1275 <xref linkend=
"planner-stats-details"/>.
1279 <sect2 id=
"planner-stats-extended">
1280 <title>Extended Statistics
</title>
1282 <indexterm zone=
"planner-stats-extended">
1283 <primary>statistics
</primary>
1284 <secondary>of the planner
</secondary>
1288 <primary>correlation
</primary>
1289 <secondary>in the query planner
</secondary>
1293 <primary>pg_statistic_ext
</primary>
1297 <primary>pg_statistic_ext_data
</primary>
1301 It is common to see slow queries running bad execution plans because
1302 multiple columns used in the query clauses are correlated.
1303 The planner normally assumes that multiple conditions
1304 are independent of each other,
1305 an assumption that does not hold when column values are correlated.
1306 Regular statistics, because of their per-individual-column nature,
1307 cannot capture any knowledge about cross-column correlation.
1308 However,
<productname>PostgreSQL
</productname> has the ability to compute
1309 <firstterm>multivariate statistics
</firstterm>, which can capture
1314 Because the number of possible column combinations is very large,
1315 it's impractical to compute multivariate statistics automatically.
1316 Instead,
<firstterm>extended statistics objects
</firstterm>, more often
1317 called just
<firstterm>statistics objects
</firstterm>, can be created to instruct
1318 the server to obtain statistics across interesting sets of columns.
1322 Statistics objects are created using the
1323 <link linkend=
"sql-createstatistics"><command>CREATE STATISTICS
</command></link> command.
1324 Creation of such an object merely creates a catalog entry expressing
1325 interest in the statistics. Actual data collection is performed
1326 by
<command>ANALYZE
</command> (either a manual command, or background
1327 auto-analyze). The collected values can be examined in the
1328 <link linkend=
"catalog-pg-statistic-ext-data"><structname>pg_statistic_ext_data
</structname></link>
1333 <command>ANALYZE
</command> computes extended statistics based on the same
1334 sample of table rows that it takes for computing regular single-column
1335 statistics. Since the sample size is increased by increasing the
1336 statistics target for the table or any of its columns (as described in
1337 the previous section), a larger statistics target will normally result in
1338 more accurate extended statistics, as well as more time spent calculating
1343 The following subsections describe the kinds of extended statistics
1344 that are currently supported.
1347 <sect3 id=
"planner-stats-extended-functional-deps">
1348 <title>Functional Dependencies
</title>
1351 The simplest kind of extended statistics tracks
<firstterm>functional
1352 dependencies
</firstterm>, a concept used in definitions of database normal forms.
1353 We say that column
<structfield>b
</structfield> is functionally dependent on
1354 column
<structfield>a
</structfield> if knowledge of the value of
1355 <structfield>a
</structfield> is sufficient to determine the value
1356 of
<structfield>b
</structfield>, that is there are no two rows having the same value
1357 of
<structfield>a
</structfield> but different values of
<structfield>b
</structfield>.
1358 In a fully normalized database, functional dependencies should exist
1359 only on primary keys and superkeys. However, in practice many data sets
1360 are not fully normalized for various reasons; intentional
1361 denormalization for performance reasons is a common example.
1362 Even in a fully normalized database, there may be partial correlation
1363 between some columns, which can be expressed as partial functional
1368 The existence of functional dependencies directly affects the accuracy
1369 of estimates in certain queries. If a query contains conditions on
1370 both the independent and the dependent column(s), the
1371 conditions on the dependent columns do not further reduce the result
1372 size; but without knowledge of the functional dependency, the query
1373 planner will assume that the conditions are independent, resulting
1374 in underestimating the result size.
1378 To inform the planner about functional dependencies,
<command>ANALYZE
</command>
1379 can collect measurements of cross-column dependency. Assessing the
1380 degree of dependency between all sets of columns would be prohibitively
1381 expensive, so data collection is limited to those groups of columns
1382 appearing together in a statistics object defined with
1383 the
<literal>dependencies
</literal> option. It is advisable to create
1384 <literal>dependencies
</literal> statistics only for column groups that are
1385 strongly correlated, to avoid unnecessary overhead in both
1386 <command>ANALYZE
</command> and later query planning.
1390 Here is an example of collecting functional-dependency statistics:
1392 CREATE STATISTICS stts (dependencies) ON city, zip FROM zipcodes;
1396 SELECT stxname, stxkeys, stxddependencies
1397 FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid)
1398 WHERE stxname = 'stts';
1399 stxname | stxkeys | stxddependencies
1400 ---------+---------+------------------------------------------
1401 stts |
1 5 | {
"1 => 5":
1.000000,
"5 => 1":
0.423130}
1404 Here it can be seen that column
1 (zip code) fully determines column
1405 5 (city) so the coefficient is
1.0, while city only determines zip code
1406 about
42% of the time, meaning that there are many cities (
58%) that are
1407 represented by more than a single ZIP code.
1411 When computing the selectivity for a query involving functionally
1412 dependent columns, the planner adjusts the per-condition selectivity
1413 estimates using the dependency coefficients so as not to produce
1417 <sect4 id=
"planner-stats-extended-functional-deps-limits">
1418 <title>Limitations of Functional Dependencies
</title>
1421 Functional dependencies are currently only applied when considering
1422 simple equality conditions that compare columns to constant values,
1423 and
<literal>IN
</literal> clauses with constant values.
1424 They are not used to improve estimates for equality conditions
1425 comparing two columns or comparing a column to an expression, nor for
1426 range clauses,
<literal>LIKE
</literal> or any other type of condition.
1430 When estimating with functional dependencies, the planner assumes that
1431 conditions on the involved columns are compatible and hence redundant.
1432 If they are incompatible, the correct estimate would be zero rows, but
1433 that possibility is not considered. For example, given a query like
1435 SELECT * FROM zipcodes WHERE city = 'San Francisco' AND zip = '
94105';
1437 the planner will disregard the
<structfield>city
</structfield> clause as not
1438 changing the selectivity, which is correct. However, it will make
1439 the same assumption about
1441 SELECT * FROM zipcodes WHERE city = 'San Francisco' AND zip = '
90210';
1443 even though there will really be zero rows satisfying this query.
1444 Functional dependency statistics do not provide enough information
1445 to conclude that, however.
1449 In many practical situations, this assumption is usually satisfied;
1450 for example, there might be a GUI in the application that only allows
1451 selecting compatible city and ZIP code values to use in a query.
1452 But if that's not the case, functional dependencies may not be a viable
1458 <sect3 id=
"planner-stats-extended-n-distinct-counts">
1459 <title>Multivariate N-Distinct Counts
</title>
1462 Single-column statistics store the number of distinct values in each
1463 column. Estimates of the number of distinct values when combining more
1464 than one column (for example, for
<literal>GROUP BY a, b
</literal>) are
1465 frequently wrong when the planner only has single-column statistical
1466 data, causing it to select bad plans.
1470 To improve such estimates,
<command>ANALYZE
</command> can collect n-distinct
1471 statistics for groups of columns. As before, it's impractical to do
1472 this for every possible column grouping, so data is collected only for
1473 those groups of columns appearing together in a statistics object
1474 defined with the
<literal>ndistinct
</literal> option. Data will be collected
1475 for each possible combination of two or more columns from the set of
1480 Continuing the previous example, the n-distinct counts in a
1481 table of ZIP codes might look like the following:
1483 CREATE STATISTICS stts2 (ndistinct) ON city, state, zip FROM zipcodes;
1487 SELECT stxkeys AS k, stxdndistinct AS nd
1488 FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid)
1489 WHERE stxname = 'stts2';
1490 -[ RECORD
1 ]------------------------------------------------------
&zwsp;--
1492 nd | {
"1, 2":
33178,
"1, 5":
33178,
"2, 5":
27435,
"1, 2, 5":
33178}
1495 This indicates that there are three combinations of columns that
1496 have
33178 distinct values: ZIP code and state; ZIP code and city;
1497 and ZIP code, city and state (the fact that they are all equal is
1498 expected given that ZIP code alone is unique in this table). On the
1499 other hand, the combination of city and state has only
27435 distinct
1504 It's advisable to create
<literal>ndistinct
</literal> statistics objects only
1505 on combinations of columns that are actually used for grouping, and
1506 for which misestimation of the number of groups is resulting in bad
1507 plans. Otherwise, the
<command>ANALYZE
</command> cycles are just wasted.
1511 <sect3 id=
"planner-stats-extended-mcv-lists">
1512 <title>Multivariate MCV Lists
</title>
1515 Another type of statistic stored for each column are most-common value
1516 lists. This allows very accurate estimates for individual columns, but
1517 may result in significant misestimates for queries with conditions on
1522 To improve such estimates,
<command>ANALYZE
</command> can collect MCV
1523 lists on combinations of columns. Similarly to functional dependencies
1524 and n-distinct coefficients, it's impractical to do this for every
1525 possible column grouping. Even more so in this case, as the MCV list
1526 (unlike functional dependencies and n-distinct coefficients) does store
1527 the common column values. So data is collected only for those groups
1528 of columns appearing together in a statistics object defined with the
1529 <literal>mcv
</literal> option.
1533 Continuing the previous example, the MCV list for a table of ZIP codes
1534 might look like the following (unlike for simpler types of statistics,
1535 a function is required for inspection of MCV contents):
1538 CREATE STATISTICS stts3 (mcv) ON city, state FROM zipcodes;
1542 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
1543 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts3';
1545 index | values | nulls | frequency | base_frequency
1546 -------+------------------------+-------+-----------+----------------
1547 0 | {Washington, DC} | {f,f} |
0.003467 |
2.7e-05
1548 1 | {Apo, AE} | {f,f} |
0.003067 |
1.9e-05
1549 2 | {Houston, TX} | {f,f} |
0.002167 |
0.000133
1550 3 | {El Paso, TX} | {f,f} |
0.002 |
0.000113
1551 4 | {New York, NY} | {f,f} |
0.001967 |
0.000114
1552 5 | {Atlanta, GA} | {f,f} |
0.001633 |
3.3e-05
1553 6 | {Sacramento, CA} | {f,f} |
0.001433 |
7.8e-05
1554 7 | {Miami, FL} | {f,f} |
0.0014 |
6e-05
1555 8 | {Dallas, TX} | {f,f} |
0.001367 |
8.8e-05
1556 9 | {Chicago, IL} | {f,f} |
0.001333 |
5.1e-05
1560 This indicates that the most common combination of city and state is
1561 Washington in DC, with actual frequency (in the sample) about
0.35%.
1562 The base frequency of the combination (as computed from the simple
1563 per-column frequencies) is only
0.0027%, resulting in two orders of
1564 magnitude under-estimates.
1568 It's advisable to create
<acronym>MCV
</acronym> statistics objects only
1569 on combinations of columns that are actually used in conditions together,
1570 and for which misestimation of the number of groups is resulting in bad
1571 plans. Otherwise, the
<command>ANALYZE
</command> and planning cycles
1579 <sect1 id=
"explicit-joins">
1580 <title>Controlling the Planner with Explicit
<literal>JOIN
</literal> Clauses
</title>
1582 <indexterm zone=
"explicit-joins">
1583 <primary>join
</primary>
1584 <secondary>controlling the order
</secondary>
1589 to control the query planner to some extent by using the explicit
<literal>JOIN
</literal>
1590 syntax. To see why this matters, we first need some background.
1594 In a simple join query, such as:
1596 SELECT * FROM a, b, c WHERE a.id = b.id AND b.ref = c.id;
1598 the planner is free to join the given tables in any order. For
1599 example, it could generate a query plan that joins A to B, using
1600 the
<literal>WHERE
</literal> condition
<literal>a.id = b.id
</literal>, and then
1601 joins C to this joined table, using the other
<literal>WHERE
</literal>
1602 condition. Or it could join B to C and then join A to that result.
1603 Or it could join A to C and then join them with B
— but that
1604 would be inefficient, since the full Cartesian product of A and C
1605 would have to be formed, there being no applicable condition in the
1606 <literal>WHERE
</literal> clause to allow optimization of the join. (All
1607 joins in the
<productname>PostgreSQL
</productname> executor happen
1608 between two input tables, so it's necessary to build up the result
1609 in one or another of these fashions.) The important point is that
1610 these different join possibilities give semantically equivalent
1611 results but might have hugely different execution costs. Therefore,
1612 the planner will explore all of them to try to find the most
1613 efficient query plan.
1617 When a query only involves two or three tables, there aren't many join
1618 orders to worry about. But the number of possible join orders grows
1619 exponentially as the number of tables expands. Beyond ten or so input
1620 tables it's no longer practical to do an exhaustive search of all the
1621 possibilities, and even for six or seven tables planning might take an
1622 annoyingly long time. When there are too many input tables, the
1623 <productname>PostgreSQL
</productname> planner will switch from exhaustive
1624 search to a
<firstterm>genetic
</firstterm> probabilistic search
1625 through a limited number of possibilities. (The switch-over threshold is
1626 set by the
<xref linkend=
"guc-geqo-threshold"/> run-time
1628 The genetic search takes less time, but it won't
1629 necessarily find the best possible plan.
1633 When the query involves outer joins, the planner has less freedom
1634 than it does for plain (inner) joins. For example, consider:
1636 SELECT * FROM a LEFT JOIN (b JOIN c ON (b.ref = c.id)) ON (a.id = b.id);
1638 Although this query's restrictions are superficially similar to the
1639 previous example, the semantics are different because a row must be
1640 emitted for each row of A that has no matching row in the join of B and C.
1641 Therefore the planner has no choice of join order here: it must join
1642 B to C and then join A to that result. Accordingly, this query takes
1643 less time to plan than the previous query. In other cases, the planner
1644 might be able to determine that more than one join order is safe.
1647 SELECT * FROM a LEFT JOIN b ON (a.bid = b.id) LEFT JOIN c ON (a.cid = c.id);
1649 it is valid to join A to either B or C first. Currently, only
1650 <literal>FULL JOIN
</literal> completely constrains the join order. Most
1651 practical cases involving
<literal>LEFT JOIN
</literal> or
<literal>RIGHT JOIN
</literal>
1652 can be rearranged to some extent.
1656 Explicit inner join syntax (
<literal>INNER JOIN
</literal>,
<literal>CROSS
1657 JOIN
</literal>, or unadorned
<literal>JOIN
</literal>) is semantically the same as
1658 listing the input relations in
<literal>FROM
</literal>, so it does not
1659 constrain the join order.
1663 Even though most kinds of
<literal>JOIN
</literal> don't completely constrain
1664 the join order, it is possible to instruct the
1665 <productname>PostgreSQL
</productname> query planner to treat all
1666 <literal>JOIN
</literal> clauses as constraining the join order anyway.
1667 For example, these three queries are logically equivalent:
1669 SELECT * FROM a, b, c WHERE a.id = b.id AND b.ref = c.id;
1670 SELECT * FROM a CROSS JOIN b CROSS JOIN c WHERE a.id = b.id AND b.ref = c.id;
1671 SELECT * FROM a JOIN (b JOIN c ON (b.ref = c.id)) ON (a.id = b.id);
1673 But if we tell the planner to honor the
<literal>JOIN
</literal> order,
1674 the second and third take less time to plan than the first. This effect
1675 is not worth worrying about for only three tables, but it can be a
1676 lifesaver with many tables.
1680 To force the planner to follow the join order laid out by explicit
1681 <literal>JOIN
</literal>s,
1682 set the
<xref linkend=
"guc-join-collapse-limit"/> run-time parameter to
1.
1683 (Other possible values are discussed below.)
1687 You do not need to constrain the join order completely in order to
1688 cut search time, because it's OK to use
<literal>JOIN
</literal> operators
1689 within items of a plain
<literal>FROM
</literal> list. For example, consider:
1691 SELECT * FROM a CROSS JOIN b, c, d, e WHERE ...;
1693 With
<varname>join_collapse_limit
</varname> =
1, this
1694 forces the planner to join A to B before joining them to other tables,
1695 but doesn't constrain its choices otherwise. In this example, the
1696 number of possible join orders is reduced by a factor of
5.
1700 Constraining the planner's search in this way is a useful technique
1701 both for reducing planning time and for directing the planner to a
1702 good query plan. If the planner chooses a bad join order by default,
1703 you can force it to choose a better order via
<literal>JOIN
</literal> syntax
1704 — assuming that you know of a better order, that is. Experimentation
1709 A closely related issue that affects planning time is collapsing of
1710 subqueries into their parent query. For example, consider:
1714 (SELECT * FROM a, b, c WHERE something) AS ss
1715 WHERE somethingelse;
1717 This situation might arise from use of a view that contains a join;
1718 the view's
<literal>SELECT
</literal> rule will be inserted in place of the view
1719 reference, yielding a query much like the above. Normally, the planner
1720 will try to collapse the subquery into the parent, yielding:
1722 SELECT * FROM x, y, a, b, c WHERE something AND somethingelse;
1724 This usually results in a better plan than planning the subquery
1725 separately. (For example, the outer
<literal>WHERE
</literal> conditions might be such that
1726 joining X to A first eliminates many rows of A, thus avoiding the need to
1727 form the full logical output of the subquery.) But at the same time,
1728 we have increased the planning time; here, we have a five-way join
1729 problem replacing two separate three-way join problems. Because of the
1730 exponential growth of the number of possibilities, this makes a big
1731 difference. The planner tries to avoid getting stuck in huge join search
1732 problems by not collapsing a subquery if more than
<varname>from_collapse_limit
</varname>
1733 <literal>FROM
</literal> items would result in the parent
1734 query. You can trade off planning time against quality of plan by
1735 adjusting this run-time parameter up or down.
1739 <xref linkend=
"guc-from-collapse-limit"/> and
<xref
1740 linkend=
"guc-join-collapse-limit"/>
1741 are similarly named because they do almost the same thing: one controls
1742 when the planner will
<quote>flatten out
</quote> subqueries, and the
1743 other controls when it will flatten out explicit joins. Typically
1744 you would either set
<varname>join_collapse_limit
</varname> equal to
1745 <varname>from_collapse_limit
</varname> (so that explicit joins and subqueries
1746 act similarly) or set
<varname>join_collapse_limit
</varname> to
1 (if you want
1747 to control join order with explicit joins). But you might set them
1748 differently if you are trying to fine-tune the trade-off between planning
1753 <sect1 id=
"populate">
1754 <title>Populating a Database
</title>
1757 One might need to insert a large amount of data when first populating
1758 a database. This section contains some suggestions on how to make
1759 this process as efficient as possible.
1762 <sect2 id=
"disable-autocommit">
1763 <title>Disable Autocommit
</title>
1766 <primary>autocommit
</primary>
1767 <secondary>bulk-loading data
</secondary>
1771 When using multiple
<command>INSERT
</command>s, turn off autocommit and just do
1772 one commit at the end. (In plain
1773 SQL, this means issuing
<command>BEGIN
</command> at the start and
1774 <command>COMMIT
</command> at the end. Some client libraries might
1775 do this behind your back, in which case you need to make sure the
1776 library does it when you want it done.) If you allow each
1777 insertion to be committed separately,
1778 <productname>PostgreSQL
</productname> is doing a lot of work for
1779 each row that is added. An additional benefit of doing all
1780 insertions in one transaction is that if the insertion of one row
1781 were to fail then the insertion of all rows inserted up to that
1782 point would be rolled back, so you won't be stuck with partially
1787 <sect2 id=
"populate-copy-from">
1788 <title>Use
<command>COPY
</command></title>
1791 Use
<link linkend=
"sql-copy"><command>COPY
</command></link> to load
1792 all the rows in one command, instead of using a series of
1793 <command>INSERT
</command> commands. The
<command>COPY
</command>
1794 command is optimized for loading large numbers of rows; it is less
1795 flexible than
<command>INSERT
</command>, but incurs significantly
1796 less overhead for large data loads. Since
<command>COPY
</command>
1797 is a single command, there is no need to disable autocommit if you
1798 use this method to populate a table.
1802 If you cannot use
<command>COPY
</command>, it might help to use
<link
1803 linkend=
"sql-prepare"><command>PREPARE
</command></link> to create a
1804 prepared
<command>INSERT
</command> statement, and then use
1805 <command>EXECUTE
</command> as many times as required. This avoids
1806 some of the overhead of repeatedly parsing and planning
1807 <command>INSERT
</command>. Different interfaces provide this facility
1808 in different ways; look for
<quote>prepared statements
</quote> in the interface
1813 Note that loading a large number of rows using
1814 <command>COPY
</command> is almost always faster than using
1815 <command>INSERT
</command>, even if
<command>PREPARE
</command> is used and
1816 multiple insertions are batched into a single transaction.
1820 <command>COPY
</command> is fastest when used within the same
1821 transaction as an earlier
<command>CREATE TABLE
</command> or
1822 <command>TRUNCATE
</command> command. In such cases no WAL
1823 needs to be written, because in case of an error, the files
1824 containing the newly loaded data will be removed anyway.
1825 However, this consideration only applies when
1826 <xref linkend=
"guc-wal-level"/> is
<literal>minimal
</literal>
1827 as all commands must write WAL otherwise.
1832 <sect2 id=
"populate-rm-indexes">
1833 <title>Remove Indexes
</title>
1836 If you are loading a freshly created table, the fastest method is to
1837 create the table, bulk load the table's data using
1838 <command>COPY
</command>, then create any indexes needed for the
1839 table. Creating an index on pre-existing data is quicker than
1840 updating it incrementally as each row is loaded.
1844 If you are adding large amounts of data to an existing table,
1845 it might be a win to drop the indexes,
1846 load the table, and then recreate the indexes. Of course, the
1847 database performance for other users might suffer
1848 during the time the indexes are missing. One should also think
1849 twice before dropping a unique index, since the error checking
1850 afforded by the unique constraint will be lost while the index is
1855 <sect2 id=
"populate-rm-fkeys">
1856 <title>Remove Foreign Key Constraints
</title>
1859 Just as with indexes, a foreign key constraint can be checked
1860 <quote>in bulk
</quote> more efficiently than row-by-row. So it might be
1861 useful to drop foreign key constraints, load data, and re-create
1862 the constraints. Again, there is a trade-off between data load
1863 speed and loss of error checking while the constraint is missing.
1867 What's more, when you load data into a table with existing foreign key
1868 constraints, each new row requires an entry in the server's list of
1869 pending trigger events (since it is the firing of a trigger that checks
1870 the row's foreign key constraint). Loading many millions of rows can
1871 cause the trigger event queue to overflow available memory, leading to
1872 intolerable swapping or even outright failure of the command. Therefore
1873 it may be
<emphasis>necessary
</emphasis>, not just desirable, to drop and re-apply
1874 foreign keys when loading large amounts of data. If temporarily removing
1875 the constraint isn't acceptable, the only other recourse may be to split
1876 up the load operation into smaller transactions.
1880 <sect2 id=
"populate-work-mem">
1881 <title>Increase
<varname>maintenance_work_mem
</varname></title>
1884 Temporarily increasing the
<xref linkend=
"guc-maintenance-work-mem"/>
1885 configuration variable when loading large amounts of data can
1886 lead to improved performance. This will help to speed up
<command>CREATE
1887 INDEX
</command> commands and
<command>ALTER TABLE ADD FOREIGN KEY
</command> commands.
1888 It won't do much for
<command>COPY
</command> itself, so this advice is
1889 only useful when you are using one or both of the above techniques.
1893 <sect2 id=
"populate-max-wal-size">
1894 <title>Increase
<varname>max_wal_size
</varname></title>
1897 Temporarily increasing the
<xref linkend=
"guc-max-wal-size"/>
1898 configuration variable can also
1899 make large data loads faster. This is because loading a large
1900 amount of data into
<productname>PostgreSQL
</productname> will
1901 cause checkpoints to occur more often than the normal checkpoint
1902 frequency (specified by the
<varname>checkpoint_timeout
</varname>
1903 configuration variable). Whenever a checkpoint occurs, all dirty
1904 pages must be flushed to disk. By increasing
1905 <varname>max_wal_size
</varname> temporarily during bulk
1906 data loads, the number of checkpoints that are required can be
1911 <sect2 id=
"populate-pitr">
1912 <title>Disable WAL Archival and Streaming Replication
</title>
1915 When loading large amounts of data into an installation that uses
1916 WAL archiving or streaming replication, it might be faster to take a
1917 new base backup after the load has completed than to process a large
1918 amount of incremental WAL data. To prevent incremental WAL logging
1919 while loading, disable archiving and streaming replication, by setting
1920 <xref linkend=
"guc-wal-level"/> to
<literal>minimal
</literal>,
1921 <xref linkend=
"guc-archive-mode"/> to
<literal>off
</literal>, and
1922 <xref linkend=
"guc-max-wal-senders"/> to zero.
1923 But note that changing these settings requires a server restart,
1924 and makes any base backups taken before unavailable for archive
1925 recovery and standby server, which may lead to data loss.
1929 Aside from avoiding the time for the archiver or WAL sender to process the
1930 WAL data, doing this will actually make certain commands faster, because
1931 they do not to write WAL at all if
<varname>wal_level
</varname>
1932 is
<literal>minimal
</literal> and the current subtransaction (or top-level
1933 transaction) created or truncated the table or index they change. (They
1934 can guarantee crash safety more cheaply by doing
1935 an
<function>fsync
</function> at the end than by writing WAL.)
1939 <sect2 id=
"populate-analyze">
1940 <title>Run
<command>ANALYZE
</command> Afterwards
</title>
1943 Whenever you have significantly altered the distribution of data
1944 within a table, running
<link linkend=
"sql-analyze"><command>ANALYZE
</command></link> is strongly recommended. This
1945 includes bulk loading large amounts of data into the table. Running
1946 <command>ANALYZE
</command> (or
<command>VACUUM ANALYZE
</command>)
1947 ensures that the planner has up-to-date statistics about the
1948 table. With no statistics or obsolete statistics, the planner might
1949 make poor decisions during query planning, leading to poor
1950 performance on any tables with inaccurate or nonexistent
1951 statistics. Note that if the autovacuum daemon is enabled, it might
1952 run
<command>ANALYZE
</command> automatically; see
1953 <xref linkend=
"vacuum-for-statistics"/>
1954 and
<xref linkend=
"autovacuum"/> for more information.
1958 <sect2 id=
"populate-pg-dump">
1959 <title>Some Notes about
<application>pg_dump
</application></title>
1962 Dump scripts generated by
<application>pg_dump
</application> automatically apply
1963 several, but not all, of the above guidelines. To restore a
1964 <application>pg_dump
</application> dump as quickly as possible, you need to
1965 do a few extra things manually. (Note that these points apply while
1966 <emphasis>restoring
</emphasis> a dump, not while
<emphasis>creating
</emphasis> it.
1967 The same points apply whether loading a text dump with
1968 <application>psql
</application> or using
<application>pg_restore
</application> to load
1969 from a
<application>pg_dump
</application> archive file.)
1973 By default,
<application>pg_dump
</application> uses
<command>COPY
</command>, and when
1974 it is generating a complete schema-and-data dump, it is careful to
1975 load data before creating indexes and foreign keys. So in this case
1976 several guidelines are handled automatically. What is left
1977 for you to do is to:
1981 Set appropriate (i.e., larger than normal) values for
1982 <varname>maintenance_work_mem
</varname> and
1983 <varname>max_wal_size
</varname>.
1988 If using WAL archiving or streaming replication, consider disabling
1989 them during the restore. To do that, set
<varname>archive_mode
</varname>
1990 to
<literal>off
</literal>,
1991 <varname>wal_level
</varname> to
<literal>minimal
</literal>, and
1992 <varname>max_wal_senders
</varname> to zero before loading the dump.
1993 Afterwards, set them back to the right values and take a fresh
1999 Experiment with the parallel dump and restore modes of both
2000 <application>pg_dump
</application> and
<application>pg_restore
</application> and find the
2001 optimal number of concurrent jobs to use. Dumping and restoring in
2002 parallel by means of the
<option>-j
</option> option should give you a
2003 significantly higher performance over the serial mode.
2008 Consider whether the whole dump should be restored as a single
2009 transaction. To do that, pass the
<option>-
1</option> or
2010 <option>--single-transaction
</option> command-line option to
2011 <application>psql
</application> or
<application>pg_restore
</application>. When using this
2012 mode, even the smallest of errors will rollback the entire restore,
2013 possibly discarding many hours of processing. Depending on how
2014 interrelated the data is, that might seem preferable to manual cleanup,
2015 or not.
<command>COPY
</command> commands will run fastest if you use a single
2016 transaction and have WAL archiving turned off.
2021 If multiple CPUs are available in the database server, consider using
2022 <application>pg_restore
</application>'s
<option>--jobs
</option> option. This
2023 allows concurrent data loading and index creation.
2028 Run
<command>ANALYZE
</command> afterwards.
2035 A data-only dump will still use
<command>COPY
</command>, but it does not
2036 drop or recreate indexes, and it does not normally touch foreign
2041 You can get the effect of disabling foreign keys by using
2042 the
<option>--disable-triggers
</option> option
— but realize that
2043 that eliminates, rather than just postpones, foreign key
2044 validation, and so it is possible to insert bad data if you use it.
2048 So when loading a data-only dump, it is up to you to drop and recreate
2049 indexes and foreign keys if you wish to use those techniques.
2050 It's still useful to increase
<varname>max_wal_size
</varname>
2051 while loading the data, but don't bother increasing
2052 <varname>maintenance_work_mem
</varname>; rather, you'd do that while
2053 manually recreating indexes and foreign keys afterwards.
2054 And don't forget to
<command>ANALYZE
</command> when you're done; see
2055 <xref linkend=
"vacuum-for-statistics"/>
2056 and
<xref linkend=
"autovacuum"/> for more information.
2061 <sect1 id=
"non-durability">
2062 <title>Non-Durable Settings
</title>
2064 <indexterm zone=
"non-durability">
2065 <primary>non-durable
</primary>
2069 Durability is a database feature that guarantees the recording of
2070 committed transactions even if the server crashes or loses
2071 power. However, durability adds significant database overhead,
2072 so if your site does not require such a guarantee,
2073 <productname>PostgreSQL
</productname> can be configured to run
2074 much faster. The following are configuration changes you can make
2075 to improve performance in such cases. Except as noted below, durability
2076 is still guaranteed in case of a crash of the database software;
2077 only an abrupt operating system crash creates a risk of data loss
2078 or corruption when these settings are used.
2083 Place the database cluster's data directory in a memory-backed
2084 file system (i.e.,
<acronym>RAM
</acronym> disk). This eliminates all
2085 database disk I/O, but limits data storage to the amount of
2086 available memory (and perhaps swap).
2092 Turn off
<xref linkend=
"guc-fsync"/>; there is no need to flush
2099 Turn off
<xref linkend=
"guc-synchronous-commit"/>; there might be no
2100 need to force
<acronym>WAL
</acronym> writes to disk on every
2101 commit. This setting does risk transaction loss (though not data
2102 corruption) in case of a crash of the
<emphasis>database
</emphasis>.
2108 Turn off
<xref linkend=
"guc-full-page-writes"/>; there is no need
2109 to guard against partial page writes.
2115 Increase
<xref linkend=
"guc-max-wal-size"/> and
<xref
2116 linkend=
"guc-checkpoint-timeout"/>; this reduces the frequency
2117 of checkpoints, but increases the storage requirements of
2118 <filename>/pg_wal
</filename>.
2124 Create
<link linkend=
"sql-createtable-unlogged">unlogged
2125 tables
</link> to avoid
<acronym>WAL
</acronym> writes, though it
2126 makes the tables non-crash-safe.