diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index fd4be5d74a..d173af9b9a 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -2533,8 +2533,8 @@ SET ENABLE_SEQSCAN TO OFF; Sets the planner's estimate of the cost of a disk page fetch that is part of a series of sequential fetches. The default is 1.0. - This value can be overridden for a particular tablespace by setting - the tablespace parameter of the same name + This value can be overridden for tables and indexes in a particular + tablespace by setting the tablespace parameter of the same name (see ). @@ -2549,8 +2549,8 @@ SET ENABLE_SEQSCAN TO OFF; Sets the planner's estimate of the cost of a non-sequentially-fetched disk page. The default is 4.0. - This value can be overridden for a particular tablespace by setting - the tablespace parameter of the same name + This value can be overridden for tables and indexes in a particular + tablespace by setting the tablespace parameter of the same name (see ). diff --git a/doc/src/sgml/perform.sgml b/doc/src/sgml/perform.sgml index 2d115fa26e..8e695fd540 100644 --- a/doc/src/sgml/perform.sgml +++ b/doc/src/sgml/perform.sgml @@ -14,8 +14,8 @@ and tuning PostgreSQL performance. - - Using <command>EXPLAIN</command> + + Using <command>EXPLAIN</command> EXPLAIN @@ -31,84 +31,100 @@ plan to match the query structure and the properties of the data is absolutely critical for good performance, so the system includes a complex planner that tries to choose good plans. - You can use the - command + You can use the command to see what query plan the planner creates for any query. - Plan-reading is an art that deserves an extensive tutorial, which - this is not; but here is some basic information. + Plan-reading is an art that requires some experience to master, + but this section attempts to cover the basics. + + Examples in this section are drawn from the regression test database + after doing a VACUUM ANALYZE, using 9.2 development sources. + You should be able to get similar results if you try the examples + yourself, but your estimated costs and row counts might vary slightly + because ANALYZE's statistics are random samples rather + than exact, and because costs are inherently somewhat platform-dependent. + + + + The examples use EXPLAIN's default text output + format, which is compact and convenient for humans to read. + If you want to feed EXPLAIN's output to a program for further + analysis, you should use one of its machine-readable output formats + (XML, JSON, or YAML) instead. + + + + <command>EXPLAIN</command> Basics + The structure of a query plan is a tree of plan nodes. - Nodes at the bottom level of the tree are table scan nodes: they return raw rows + Nodes at the bottom level of the tree are scan nodes: they return raw rows from a table. There are different types of scan nodes for different table access methods: sequential scans, index scans, and bitmap index - scans. If the query requires joining, aggregation, sorting, or other + scans. There are also non-table row sources, such as VALUES + clauses and set-returning functions in FROM, which have their + own scan node types. + If the query requires joining, aggregation, sorting, or other operations on the raw rows, then there will be additional nodes above the scan nodes to perform these operations. Again, there is usually more than one possible way to do these operations, so different node types can appear here too. The output of EXPLAIN has one line for each node in the plan tree, showing the basic node type plus the cost estimates that the planner - made for the execution of that plan node. The first line (topmost node) - has the estimated total execution cost for the plan; it is this number - that the planner seeks to minimize. + made for the execution of that plan node. Additional lines might appear, + indented from the node's summary line, + to show additional properties of the node. + The very first line (the summary line for the topmost + node) has the estimated total execution cost for the plan; it is this + number that the planner seeks to minimize. Here is a trivial example, just to show what the output looks like: - - - Examples in this section are drawn from the regression test database - after doing a VACUUM ANALYZE, using 8.2 development sources. - You should be able to get similar results if you try the examples yourself, - but your estimated costs and row counts might vary slightly - because ANALYZE's statistics are random samples rather - than exact. - - - + EXPLAIN SELECT * FROM tenk1; QUERY PLAN ------------------------------------------------------------- Seq Scan on tenk1 (cost=0.00..458.00 rows=10000 width=244) - + - The numbers that are quoted by EXPLAIN are (left + Since this query has no WHERE clause, it must scan all the + rows of the table, so the planner has chosen to use a simple sequential + scan plan. The numbers that are quoted in parentheses are (left to right): - Estimated start-up cost (time expended before the output scan can start, - e.g., time to do the sorting in a sort node) + Estimated start-up cost. This is the time expended before the output + phase can begin, e.g., time to do the sorting in a sort node. - Estimated total cost (if all rows are retrieved, though they might - not be; e.g., a query with a LIMIT clause will stop - short of paying the total cost of the Limit plan node's - input node) + Estimated total cost. This is stated on the assumption that the plan + node is run to completion, i.e., all available rows are retrieved. + In practice a node's parent node might stop short of reading all + available rows (see the LIMIT example below). - Estimated number of rows output by this plan node (again, only if - executed to completion) + Estimated number of rows output by this plan node. Again, the node + is assumed to be run to completion. - Estimated average width (in bytes) of rows output by this plan - node + Estimated average width of rows output by this plan node (in bytes). @@ -120,12 +136,12 @@ EXPLAIN SELECT * FROM tenk1; Traditional practice is to measure the costs in units of disk page fetches; that is, is conventionally set to 1.0 and the other cost parameters are set relative - to that. (The examples in this section are run with the default cost - parameters.) + to that. The examples in this section are run with the default cost + parameters. - It's important to note that the cost of an upper-level node includes + It's important to understand that the cost of an upper-level node includes the cost of all its child nodes. It's also important to realize that the cost only reflects things that the planner cares about. In particular, the cost does not consider the time spent transmitting @@ -136,30 +152,29 @@ EXPLAIN SELECT * FROM tenk1; - The rows value is a little tricky - because it is not the - number of rows processed or scanned by the plan node. It is usually less, - reflecting the estimated selectivity of any WHERE-clause - conditions that are being - applied at the node. Ideally the top-level rows estimate will - approximate the number of rows actually returned, updated, or deleted - by the query. + The rows value is a little tricky because it is + not the number of rows processed or scanned by the + plan node, but rather the number emitted by the node. This is often + less than the number scanned, as a result of filtering by any + WHERE-clause conditions that are being applied at the node. + Ideally the top-level rows estimate will approximate the number of rows + actually returned, updated, or deleted by the query. Returning to our example: - + EXPLAIN SELECT * FROM tenk1; QUERY PLAN ------------------------------------------------------------- Seq Scan on tenk1 (cost=0.00..458.00 rows=10000 width=244) - + - This is about as straightforward as it gets. If you do: + These numbers are derived very straightforwardly. If you do: SELECT relpages, reltuples FROM pg_class WHERE relname = 'tenk1'; @@ -174,23 +189,24 @@ SELECT relpages, reltuples FROM pg_class WHERE relname = 'tenk1'; - Now let's modify the original query to add a WHERE condition: + Now let's modify the query to add a WHERE condition: - + EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 7000; QUERY PLAN ------------------------------------------------------------ - Seq Scan on tenk1 (cost=0.00..483.00 rows=7033 width=244) + Seq Scan on tenk1 (cost=0.00..483.00 rows=7001 width=244) Filter: (unique1 < 7000) - + Notice that the EXPLAIN output shows the WHERE - clause being applied as a filter condition; this means that + clause being applied as a filter condition attached to the Seq + Scan plan node. This means that the plan node checks the condition for each row it scans, and outputs only the ones that pass the condition. - The estimate of output rows has been reduced because of the WHERE - clause. + The estimate of output rows has been reduced because of the + WHERE clause. However, the scan will still have to visit all 10000 rows, so the cost hasn't decreased; in fact it has gone up a bit (by 10000 * , to be exact) to reflect the extra CPU @@ -200,7 +216,7 @@ EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 7000; The actual number of rows this query would select is 7000, but the rows estimate is only approximate. If you try to duplicate this experiment, - you will probably get a slightly different estimate; moreover, it will + you will probably get a slightly different estimate; moreover, it can change after each ANALYZE command, because the statistics produced by ANALYZE are taken from a randomized sample of the table. @@ -209,22 +225,22 @@ EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 7000; Now, let's make the condition more restrictive: - + EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 100; QUERY PLAN ------------------------------------------------------------------------------ - Bitmap Heap Scan on tenk1 (cost=2.37..232.35 rows=106 width=244) + Bitmap Heap Scan on tenk1 (cost=5.03..229.17 rows=101 width=244) Recheck Cond: (unique1 < 100) - -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..2.37 rows=106 width=0) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..5.01 rows=101 width=0) Index Cond: (unique1 < 100) - + - Here the planner has decided to use a two-step plan: the bottom plan + Here the planner has decided to use a two-step plan: the child plan node visits an index to find the locations of rows matching the index condition, and then the upper plan node actually fetches those rows - from the table itself. Fetching the rows separately is much more - expensive than sequentially reading them, but because not all the pages + from the table itself. Fetching rows separately is much more + expensive than reading them sequentially, but because not all the pages of the table have to be visited, this is still cheaper than a sequential scan. (The reason for using two plan levels is that the upper plan node sorts the row locations identified by the index into physical order @@ -234,65 +250,67 @@ EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 100; - If the WHERE condition is selective enough, the planner might - switch to a simple index scan plan: + Now let's add another condition to the WHERE clause: - -EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 3; + +EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 100 AND stringu1 = 'xxx'; QUERY PLAN ------------------------------------------------------------------------------ - Index Scan using tenk1_unique1 on tenk1 (cost=0.00..10.00 rows=2 width=244) - Index Cond: (unique1 < 3) - - - In this case the table rows are fetched in index order, which makes them - even more expensive to read, but there are so few that the extra cost - of sorting the row locations is not worth it. You'll most often see - this plan type for queries that fetch just a single row, and for queries - that have an ORDER BY condition that matches the index - order. - - - - Add another condition to the WHERE clause: - - -EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 3 AND stringu1 = 'xxx'; - - QUERY PLAN ------------------------------------------------------------------------------- - Index Scan using tenk1_unique1 on tenk1 (cost=0.00..10.01 rows=1 width=244) - Index Cond: (unique1 < 3) + Bitmap Heap Scan on tenk1 (cost=5.01..229.40 rows=1 width=244) + Recheck Cond: (unique1 < 100) Filter: (stringu1 = 'xxx'::name) - + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..5.01 rows=101 width=0) + Index Cond: (unique1 < 100) + The added condition stringu1 = 'xxx' reduces the - output-rows estimate, but not the cost because we still have to visit the - same set of rows. Notice that the stringu1 clause - cannot be applied as an index condition (since this index is only on - the unique1 column). Instead it is applied as a filter on + output-rowcount estimate, but not the cost because we still have to visit + the same set of rows. Notice that the stringu1 clause + cannot be applied as an index condition, since this index is only on + the unique1 column. Instead it is applied as a filter on the rows retrieved by the index. Thus the cost has actually gone up slightly to reflect this extra checking. - If there are indexes on several columns referenced in WHERE, the - planner might choose to use an AND or OR combination of the indexes: + In some cases the planner will prefer a simple index scan plan: - + +EXPLAIN SELECT * FROM tenk1 WHERE unique1 = 42; + + QUERY PLAN +----------------------------------------------------------------------------- + Index Scan using tenk1_unique1 on tenk1 (cost=0.00..8.27 rows=1 width=244) + Index Cond: (unique1 = 42) + + + In this type of plan the table rows are fetched in index order, which + makes them even more expensive to read, but there are so few that the + extra cost of sorting the row locations is not worth it. You'll most + often see this plan type for queries that fetch just a single row. It's + also often used for queries that have an ORDER BY condition + that matches the index order, because then no extra sort step is needed to + satisfy the ORDER BY. + + + + If there are indexes on several columns referenced in WHERE, + the planner might choose to use an AND or OR combination of the indexes: + + EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 100 AND unique2 > 9000; QUERY PLAN ------------------------------------------------------------------------------------- - Bitmap Heap Scan on tenk1 (cost=11.27..49.11 rows=11 width=244) + Bitmap Heap Scan on tenk1 (cost=25.01..60.14 rows=10 width=244) Recheck Cond: ((unique1 < 100) AND (unique2 > 9000)) - -> BitmapAnd (cost=11.27..11.27 rows=11 width=0) - -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..2.37 rows=106 width=0) + -> BitmapAnd (cost=25.01..25.01 rows=10 width=0) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..5.01 rows=101 width=0) Index Cond: (unique1 < 100) - -> Bitmap Index Scan on tenk1_unique2 (cost=0.00..8.65 rows=1042 width=0) + -> Bitmap Index Scan on tenk1_unique2 (cost=0.00..19.74 rows=999 width=0) Index Cond: (unique2 > 9000) - + But this requires visiting both indexes, so it's not necessarily a win compared to using just one index and treating the other condition as @@ -301,51 +319,178 @@ EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 100 AND unique2 > 9000; - Let's try joining two tables, using the columns we have been discussing: + Here is an example showing the effects of LIMIT: - -EXPLAIN SELECT * -FROM tenk1 t1, tenk2 t2 -WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2; + +EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 100 AND unique2 > 9000 LIMIT 2; - QUERY PLAN --------------------------------------------------------------------------------------- - Nested Loop (cost=2.37..553.11 rows=106 width=488) - -> Bitmap Heap Scan on tenk1 t1 (cost=2.37..232.35 rows=106 width=244) - Recheck Cond: (unique1 < 100) - -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..2.37 rows=106 width=0) - Index Cond: (unique1 < 100) - -> Index Scan using tenk2_unique2 on tenk2 t2 (cost=0.00..3.01 rows=1 width=244) - Index Cond: (unique2 = t1.unique2) - + QUERY PLAN +------------------------------------------------------------------------------------- + Limit (cost=0.00..14.25 rows=2 width=244) + -> Index Scan using tenk1_unique2 on tenk1 (cost=0.00..71.23 rows=10 width=244) + Index Cond: (unique2 > 9000) + Filter: (unique1 < 100) + - In this nested-loop join, the outer (upper) scan is the same bitmap index scan we - saw earlier, and so its cost and row count are the same because we are - applying the WHERE clause unique1 < 100 + This is the same query as above, but we added a LIMIT so that + not all the rows need be retrieved, and the planner changed its mind about + what to do. Notice that the total cost and row count of the Index Scan + node are shown as if it were run to completion. However, the Limit node + is expected to stop after retrieving only a fifth of those rows, so its + total cost is only a fifth as much, and that's the actual estimated cost + of the query. This plan is preferred over adding a Limit node to the + previous plan because the Limit could not avoid paying the startup cost + of the bitmap scan, so the total cost would be something over 25 units + with that approach. + + + + Let's try joining two tables, using the columns we have been discussing: + + +EXPLAIN SELECT * +FROM tenk1 t1, tenk2 t2 +WHERE t1.unique1 < 10 AND t1.unique2 = t2.unique2; + + QUERY PLAN +-------------------------------------------------------------------------------------- + Nested Loop (cost=4.33..118.25 rows=10 width=488) + -> Bitmap Heap Scan on tenk1 t1 (cost=4.33..39.44 rows=10 width=244) + Recheck Cond: (unique1 < 10) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..4.33 rows=10 width=0) + Index Cond: (unique1 < 10) + -> Index Scan using tenk2_unique2 on tenk2 t2 (cost=0.00..7.87 rows=1 width=244) + Index Cond: (unique2 = t1.unique2) + + + + + In this plan, we have a nested-loop join node with two table scans as + inputs, or children. The indentation of the node summary lines reflects + the plan tree structure. The join's first, or outer, child + is a bitmap scan similar to those we saw before. Its cost and row count + are the same as we'd get from SELECT ... WHERE unique1 < 10 + because we are + applying the WHERE clause unique1 < 10 at that node. The t1.unique2 = t2.unique2 clause is not relevant yet, - so it doesn't affect the row count of the outer scan. For the inner (lower) scan, the - unique2 value of the current outer-scan row is plugged into - the inner index scan to produce an index condition like - unique2 = constant. - So we get the same inner-scan plan and costs that we'd get from, say, - EXPLAIN SELECT * FROM tenk2 WHERE unique2 = 42. The + so it doesn't affect the row count of the outer scan. The nested-loop + join node will run its second, + or inner child once for each row obtained from the outer child. + Column values from the current outer row can be plugged into the inner + scan; here, the t1.unique2 value from the outer row is available, + so we get a plan and costs similar to what we saw above for a simple + SELECT ... WHERE t2.unique2 = constant case. + (The estimated cost is actually a bit lower than what was seen above, + as a result of caching that's expected to occur during the repeated + indexscans on t2.) The costs of the loop node are then set on the basis of the cost of the outer - scan, plus one repetition of the inner scan for each outer row (106 * 3.01, + scan, plus one repetition of the inner scan for each outer row (10 * 7.87, here), plus a little CPU time for join processing. In this example the join's output row count is the same as the product of the two scans' row counts, but that's not true in all cases because - you can have WHERE clauses that mention both tables + there can be additional WHERE clauses that mention both tables and so can only be applied at the join point, not to either input scan. - For example, if we added - WHERE ... AND t1.hundred < t2.hundred, - that would decrease the output row count of the join node, but not change - either input scan. + For example, if we add one more condition: + + +EXPLAIN SELECT * +FROM tenk1 t1, tenk2 t2 +WHERE t1.unique1 < 10 AND t1.unique2 = t2.unique2 AND t1.hundred < t2.hundred; + + QUERY PLAN +-------------------------------------------------------------------------------------- + Nested Loop (cost=4.33..118.28 rows=3 width=488) + Join Filter: (t1.hundred < t2.hundred) + -> Bitmap Heap Scan on tenk1 t1 (cost=4.33..39.44 rows=10 width=244) + Recheck Cond: (unique1 < 10) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..4.33 rows=10 width=0) + Index Cond: (unique1 < 10) + -> Index Scan using tenk2_unique2 on tenk2 t2 (cost=0.00..7.87 rows=1 width=244) + Index Cond: (unique2 = t1.unique2) + + + The extra condition t1.hundred < t2.hundred can't be + tested in the tenk2_unique2 index, so it's applied at the + join node. This reduces the estimated output row count of the join node, + but does not change either input scan. + + + + When dealing with outer joins, you might see join plan nodes with both + Join Filter and plain Filter conditions attached. + Join Filter conditions come from the outer join's ON clause, + so a row that fails the Join Filter condition could still get emitted as + a null-extended row. But a plain Filter condition is applied after the + outer-join rules and so acts to remove rows unconditionally. In an inner + join there is no semantic difference between these types of filters. + + + + If we change the query's selectivity a bit, we might get a very different + join plan: + + +EXPLAIN SELECT * +FROM tenk1 t1, tenk2 t2 +WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2; + + QUERY PLAN +------------------------------------------------------------------------------------------ + Hash Join (cost=230.43..713.94 rows=101 width=488) + Hash Cond: (t2.unique2 = t1.unique2) + -> Seq Scan on tenk2 t2 (cost=0.00..445.00 rows=10000 width=244) + -> Hash (cost=229.17..229.17 rows=101 width=244) + -> Bitmap Heap Scan on tenk1 t1 (cost=5.03..229.17 rows=101 width=244) + Recheck Cond: (unique1 < 100) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..5.01 rows=101 width=0) + Index Cond: (unique1 < 100) + + + + + Here, the planner has chosen to use a hash join, in which rows of one + table are entered into an in-memory hash table, after which the other + table is scanned and the hash table is probed for matches to each row. + Again note how the indentation reflects the plan structure: the bitmap + scan on tenk1 is the input to the Hash node, which constructs + the hash table. That's then returned to the Hash Join node, which reads + rows from its outer child plan and searches the hash table for each one. + + + + Another possible type of join is a merge join, illustrated here: + + +EXPLAIN SELECT * +FROM tenk1 t1, onek t2 +WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2; + + QUERY PLAN +------------------------------------------------------------------------------------------ + Merge Join (cost=197.83..267.93 rows=10 width=488) + Merge Cond: (t1.unique2 = t2.unique2) + -> Index Scan using tenk1_unique2 on tenk1 t1 (cost=0.00..656.25 rows=101 width=244) + Filter: (unique1 < 100) + -> Sort (cost=197.83..200.33 rows=1000 width=244) + Sort Key: t2.unique2 + -> Seq Scan on onek t2 (cost=0.00..148.00 rows=1000 width=244) + + + + + Merge join requires its input data to be sorted on the join keys. In this + plan the tenk1 data is sorted by using an index scan to visit + the rows in the correct order, but a sequential scan and sort is preferred + for onek, because there are many more rows to be visited in + that table. + (Seqscan-and-sort frequently beats an indexscan for sorting many rows, + because of the nonsequential disk access required by the indexscan.) @@ -354,111 +499,283 @@ WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2; flags described in . (This is a crude tool, but useful. See also .) + For example, if we're unconvinced that seqscan-and-sort is the best way to + deal with table onek in the previous example, we could try + + +SET enable_sort = off; - -SET enable_nestloop = off; EXPLAIN SELECT * -FROM tenk1 t1, tenk2 t2 +FROM tenk1 t1, onek t2 WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2; QUERY PLAN ------------------------------------------------------------------------------------------ - Hash Join (cost=232.61..741.67 rows=106 width=488) - Hash Cond: (t2.unique2 = t1.unique2) - -> Seq Scan on tenk2 t2 (cost=0.00..458.00 rows=10000 width=244) - -> Hash (cost=232.35..232.35 rows=106 width=244) - -> Bitmap Heap Scan on tenk1 t1 (cost=2.37..232.35 rows=106 width=244) - Recheck Cond: (unique1 < 100) - -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..2.37 rows=106 width=0) - Index Cond: (unique1 < 100) - + Merge Join (cost=0.00..292.36 rows=10 width=488) + Merge Cond: (t1.unique2 = t2.unique2) + -> Index Scan using tenk1_unique2 on tenk1 t1 (cost=0.00..656.25 rows=101 width=244) + Filter: (unique1 < 100) + -> Index Scan using onek_unique2 on onek t2 (cost=0.00..224.76 rows=1000 width=244) + - This plan proposes to extract the 100 interesting rows of tenk1 - using that same old index scan, stash them into an in-memory hash table, - and then do a sequential scan of tenk2, probing into the hash table - for possible matches of t1.unique2 = t2.unique2 for each tenk2 row. - The cost to read tenk1 and set up the hash table is a start-up - cost for the hash join, since there will be no output until we can - start reading tenk2. The total time estimate for the join also - includes a hefty charge for the CPU time to probe the hash table - 10000 times. Note, however, that we are not charging 10000 times 232.35; - the hash table setup is only done once in this plan type. + which shows that the planner thinks that sorting onek by + indexscanning is about 12% more expensive than seqscan-and-sort. + Of course, the next question is whether it's right about that. + We can investigate that using EXPLAIN ANALYZE, as discussed + below. + + + + <command>EXPLAIN ANALYZE</command> + - It is possible to check the accuracy of the planner's estimated costs - by using EXPLAIN ANALYZE. This command actually executes the query, - and then displays the true run time accumulated within each plan node - along with the same estimated costs that a plain EXPLAIN shows. - For example, we might get a result like this: + It is possible to check the accuracy of the planner's estimates + by using EXPLAIN's ANALYZE option. With this + option, EXPLAIN actually executes the query, and then displays + the true row counts and true run time accumulated within each plan node, + along with the same estimates that a plain EXPLAIN + shows. For example, we might get a result like this: EXPLAIN ANALYZE SELECT * FROM tenk1 t1, tenk2 t2 -WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2; +WHERE t1.unique1 < 10 AND t1.unique2 = t2.unique2; - QUERY PLAN ----------------------------------------------------------------------------------------------------------------------------------- - Nested Loop (cost=2.37..553.11 rows=106 width=488) (actual time=1.392..12.700 rows=100 loops=1) - -> Bitmap Heap Scan on tenk1 t1 (cost=2.37..232.35 rows=106 width=244) (actual time=0.878..2.367 rows=100 loops=1) - Recheck Cond: (unique1 < 100) - -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..2.37 rows=106 width=0) (actual time=0.546..0.546 rows=100 loops=1) - Index Cond: (unique1 < 100) - -> Index Scan using tenk2_unique2 on tenk2 t2 (cost=0.00..3.01 rows=1 width=244) (actual time=0.067..0.078 rows=1 loops=100) + QUERY PLAN +--------------------------------------------------------------------------------------------------------------------------------- + Nested Loop (cost=4.33..118.25 rows=10 width=488) (actual time=0.370..1.126 rows=10 loops=1) + -> Bitmap Heap Scan on tenk1 t1 (cost=4.33..39.44 rows=10 width=244) (actual time=0.254..0.380 rows=10 loops=1) + Recheck Cond: (unique1 < 10) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..4.33 rows=10 width=0) (actual time=0.164..0.164 rows=10 loops=1) + Index Cond: (unique1 < 10) + -> Index Scan using tenk2_unique2 on tenk2 t2 (cost=0.00..7.87 rows=1 width=244) (actual time=0.041..0.048 rows=1 loops=10) Index Cond: (unique2 = t1.unique2) - Total runtime: 14.452 ms + Total runtime: 2.414 ms Note that the actual time values are in milliseconds of real time, whereas the cost estimates are expressed in arbitrary units; so they are unlikely to match up. - The thing to pay attention to is whether the ratios of actual time and - estimated costs are consistent. + The thing that's usually most important to look for is whether the + estimated row counts are reasonably close to reality. In this example + the estimates were all dead-on, but that's quite unusual in practice. In some query plans, it is possible for a subplan node to be executed more - than once. For example, the inner index scan is executed once per outer - row in the above nested-loop plan. In such cases, the + than once. For example, the inner index scan will be executed once per + outer row in the above nested-loop plan. In such cases, the loops value reports the total number of executions of the node, and the actual time and rows values shown are averages per-execution. This is done to make the numbers comparable with the way that the cost estimates are shown. Multiply by the loops value to get the total time actually spent in - the node. + the node. In the above example, we spent a total of 0.480 milliseconds + executing the indexscans on tenk2. + + + + In some cases EXPLAIN ANALYZE shows additional execution + statistics beyond the plan node execution times and row counts. + For example, Sort and Hash nodes provide extra information: + + +EXPLAIN ANALYZE SELECT * +FROM tenk1 t1, tenk2 t2 +WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2 ORDER BY t1.fivethous; + + QUERY PLAN +-------------------------------------------------------------------------------------------------------------------------------------------- + Sort (cost=717.30..717.56 rows=101 width=488) (actual time=104.950..105.327 rows=100 loops=1) + Sort Key: t1.fivethous + Sort Method: quicksort Memory: 68kB + -> Hash Join (cost=230.43..713.94 rows=101 width=488) (actual time=3.680..102.396 rows=100 loops=1) + Hash Cond: (t2.unique2 = t1.unique2) + -> Seq Scan on tenk2 t2 (cost=0.00..445.00 rows=10000 width=244) (actual time=0.046..46.219 rows=10000 loops=1) + -> Hash (cost=229.17..229.17 rows=101 width=244) (actual time=3.184..3.184 rows=100 loops=1) + Buckets: 1024 Batches: 1 Memory Usage: 27kB + -> Bitmap Heap Scan on tenk1 t1 (cost=5.03..229.17 rows=101 width=244) (actual time=0.612..1.959 rows=100 loops=1) + Recheck Cond: (unique1 < 100) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..5.01 rows=101 width=0) (actual time=0.390..0.390 rows=100 loops=1) + Index Cond: (unique1 < 100) + Total runtime: 107.392 ms + + + The Sort node shows the sort method used (in particular, whether the sort + was in-memory or on-disk) and the amount of memory or disk space needed. + The Hash node shows the number of hash buckets and batches as well as the + peak amount of memory used for the hash table. (If the number of batches + exceeds one, there will also be disk space usage involved, but that is not + shown.) + + + + Another type of extra information is the number of rows removed by a + filter condition: + + +EXPLAIN ANALYZE SELECT * FROM tenk1 WHERE ten < 7; + + QUERY PLAN +---------------------------------------------------------------------------------------------------------- + Seq Scan on tenk1 (cost=0.00..483.00 rows=7000 width=244) (actual time=0.111..59.249 rows=7000 loops=1) + Filter: (ten < 7) + Rows Removed by Filter: 3000 + Total runtime: 85.340 ms + + + These counts can be particularly valuable for filter conditions applied at + join nodes. The Rows Removed line only appears when at least + one scanned row, or potential join pair in the case of a join node, + is rejected by the filter condition. + + + + A case similar to filter conditions occurs with lossy + indexscans. For example, consider this search for polygons containing a + specific point: + + +EXPLAIN ANALYZE SELECT * FROM polygon_tbl WHERE f1 @> polygon '(0.5,2.0)'; + + QUERY PLAN +------------------------------------------------------------------------------------------------------ + Seq Scan on polygon_tbl (cost=0.00..1.05 rows=1 width=32) (actual time=0.251..0.251 rows=0 loops=1) + Filter: (f1 @> '((0.5,2))'::polygon) + Rows Removed by Filter: 4 + Total runtime: 0.517 ms + + + The planner thinks (quite correctly) that this sample table is too small + to bother with an indexscan, so we have a plain sequential scan in which + all the rows got rejected by the filter condition. But if we force an + indexscan to be used, we see: + + +SET enable_seqscan TO off; + +EXPLAIN ANALYZE SELECT * FROM polygon_tbl WHERE f1 @> polygon '(0.5,2.0)'; + + QUERY PLAN +-------------------------------------------------------------------------------------------------------------------------- + Index Scan using gpolygonind on polygon_tbl (cost=0.00..8.27 rows=1 width=32) (actual time=0.293..0.293 rows=0 loops=1) + Index Cond: (f1 @> '((0.5,2))'::polygon) + Rows Removed by Index Recheck: 1 + Total runtime: 1.054 ms + + + Here we can see that the index returned one candidate row, which was + then rejected by a recheck of the index condition. This happens because a + GiST index is lossy for polygon containment tests: it actually + returns the rows with polygons that overlap the target, and then we have + to do the exact containment test on those rows. + + + + EXPLAIN has a BUFFERS option that can be used with + ANALYZE to get even more runtime statistics: + + +EXPLAIN (ANALYZE, BUFFERS) SELECT * FROM tenk1 WHERE unique1 < 100 AND unique2 > 9000; + + QUERY PLAN +----------------------------------------------------------------------------------------------------------------------------------- + Bitmap Heap Scan on tenk1 (cost=25.07..60.23 rows=10 width=244) (actual time=3.069..3.213 rows=10 loops=1) + Recheck Cond: ((unique1 < 100) AND (unique2 > 9000)) + Buffers: shared hit=16 + -> BitmapAnd (cost=25.07..25.07 rows=10 width=0) (actual time=2.967..2.967 rows=0 loops=1) + Buffers: shared hit=7 + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..5.02 rows=102 width=0) (actual time=0.732..0.732 rows=200 loops=1) + Index Cond: (unique1 < 100) + Buffers: shared hit=2 + -> Bitmap Index Scan on tenk1_unique2 (cost=0.00..19.80 rows=1007 width=0) (actual time=2.015..2.015 rows=1009 loops=1) + Index Cond: (unique2 > 9000) + Buffers: shared hit=5 + Total runtime: 3.917 ms + + + The numbers provided by BUFFERS help to identify which parts + of the query are the most I/O-intensive. + + + + Keep in mind that because EXPLAIN ANALYZE actually + runs the query, any side-effects will happen as usual, even though + whatever results the query might output are discarded in favor of + printing the EXPLAIN data. If you want to analyze a + data-modifying query without changing your tables, you can + roll the command back afterwards, for example: + + +BEGIN; + +EXPLAIN ANALYZE UPDATE tenk1 SET hundred = hundred + 1 WHERE unique1 < 100; + + QUERY PLAN +-------------------------------------------------------------------------------------------------------------------------------- + Update on tenk1 (cost=5.03..229.42 rows=101 width=250) (actual time=81.055..81.055 rows=0 loops=1) + -> Bitmap Heap Scan on tenk1 (cost=5.03..229.42 rows=101 width=250) (actual time=0.766..3.396 rows=100 loops=1) + Recheck Cond: (unique1 < 100) + -> Bitmap Index Scan on tenk1_unique1 (cost=0.00..5.01 rows=101 width=0) (actual time=0.461..0.461 rows=100 loops=1) + Index Cond: (unique1 < 100) + Total runtime: 81.922 ms + +ROLLBACK; + + + + + As seen in this example, when the query is an INSERT, + UPDATE, or DELETE command, the actual work of + applying the table changes is done by a top-level Insert, Update, + or Delete plan node. The plan nodes underneath this node perform + the work of locating the old rows and/or computing the new data. + So above, we see the same sort of bitmap table scan we've seen already, + and its output is fed to an Update node that stores the updated rows. + It's worth noting that although the data-modifying node can take a + considerable amount of runtime (here, it's consuming the lion's share + of the time), the planner does not currently add anything to the cost + estimates to account for that work. That's because the work to be done is + the same for every correct query plan, so it doesn't affect planning + decisions. The Total runtime shown by EXPLAIN - ANALYZE includes executor start-up and shut-down time, but not - parsing, rewriting, or planning time. For INSERT, - UPDATE, and DELETE commands, the time spent - applying the table changes is charged to a top-level Insert, Update, - or Delete plan node. (The plan nodes underneath this node represent - the work of locating the old rows and/or computing the new ones.) - Time spent executing BEFORE triggers, if any, is charged to - the related Insert, Update, or Delete node, although time spent executing - AFTER triggers is not. The time spent in each trigger - (either BEFORE or AFTER) is also shown separately - and is included in total run time. - Note, however, that deferred constraint triggers will not be executed - until end of transaction and are thus not shown by + ANALYZE includes executor start-up and shut-down time, as well + as the time to run any triggers that are fired, but it does not include + parsing, rewriting, or planning time. + Time spent executing BEFORE triggers, if any, is included in + the time for the related Insert, Update, or Delete node; but time + spent executing AFTER triggers is not counted there because + AFTER triggers are fired after completion of the whole plan. + The total time spent in each trigger + (either BEFORE or AFTER) is also shown separately. + Note that deferred constraint triggers will not be executed + until end of transaction and are thus not shown at all by EXPLAIN ANALYZE. + + + + Caveats + There are two significant ways in which run times measured by EXPLAIN ANALYZE can deviate from normal execution of the same query. First, since no output rows are delivered to the client, - network transmission costs and I/O formatting costs are not included. - Second, the overhead added by EXPLAIN ANALYZE can be - significant, especially on machines with slow gettimeofday() - kernel calls. + network transmission costs and I/O conversion costs are not included. + Second, the measurement overhead added by EXPLAIN + ANALYZE can be significant, especially on machines with slow + gettimeofday() operating-system calls. - It is worth noting that EXPLAIN results should not be extrapolated - to situations other than the one you are actually testing; for example, + EXPLAIN results should not be extrapolated to situations + much different from the one you are actually testing; for example, results on a toy-sized table cannot be assumed to apply to large tables. The planner's cost estimates are not linear and so it might choose a different plan for a larger or smaller table. An extreme example @@ -466,9 +783,60 @@ WHERE t1.unique1 < 100 AND t1.unique2 = t2.unique2; always get a sequential scan plan whether indexes are available or not. The planner realizes that it's going to take one disk page read to process the table in any case, so there's no value in expending additional - page reads to look at an index. + page reads to look at an index. (We saw this happening in the + polygon_tbl example above.) - + + + There are cases in which the actual and estimated values won't match up + well, but nothing is really wrong. One such case occurs when + plan node execution is stopped short by a LIMIT or similar + effect. For example, in the LIMIT query we used before, + + +EXPLAIN ANALYZE SELECT * FROM tenk1 WHERE unique1 < 100 AND unique2 > 9000 LIMIT 2; + + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------- + Limit (cost=0.00..14.25 rows=2 width=244) (actual time=1.652..2.293 rows=2 loops=1) + -> Index Scan using tenk1_unique2 on tenk1 (cost=0.00..71.23 rows=10 width=244) (actual time=1.631..2.259 rows=2 loops=1) + Index Cond: (unique2 > 9000) + Filter: (unique1 < 100) + Rows Removed by Filter: 287 + Total runtime: 2.857 ms + + + the estimated cost and rowcount for the Index Scan node are shown as + though it were run to completion. But in reality the Limit node stopped + requesting rows after it got two, so the actual rowcount is only 2 and + the runtime is less than the cost estimate would suggest. This is not + an estimation error, only a discrepancy in the way the estimates and true + values are displayed. + + + + Merge joins also have measurement artifacts that can confuse the unwary. + A merge join will stop reading one input if it's exhausted the other input + and the next key value in the one input is greater than the last key value + of the other input; in such a case there can be no more matches and so no + need to scan the rest of the first input. This results in not reading all + of one child, with results like those mentioned for LIMIT. + Also, if the outer (first) child contains rows with duplicate key values, + the inner (second) child is backed up and rescanned for the portion of its + rows matching that key value. EXPLAIN ANALYZE counts these + repeated emissions of the same inner rows as if they were real additional + rows. When there are many outer duplicates, the reported actual rowcount + for the inner child plan node can be significantly larger than the number + of rows that are actually in the inner relation. + + + + BitmapAnd and BitmapOr nodes always report their actual rowcounts as zero, + due to implementation limitations. + + + + Statistics Used by the Planner @@ -519,10 +887,12 @@ WHERE relname LIKE 'tenk1%'; and relpages are not updated on-the-fly, and so they usually contain somewhat out-of-date values. They are updated by VACUUM, ANALYZE, and a - few DDL commands such as CREATE INDEX. A stand-alone - ANALYZE, that is one not part of VACUUM, - generates an approximate reltuples value - since it does not read every row of the table. The planner + few DDL commands such as CREATE INDEX. A VACUUM + or ANALYZE operation that does not scan the entire table + (which is commonly the case) will incrementally update the + reltuples count on the basis of the part + of the table it did scan, resulting in an approximate value. + In any case, the planner will scale the values it finds in pg_class to match the current physical table size, thus obtaining a closer approximation. @@ -571,7 +941,7 @@ SELECT attname, inherited, n_distinct, FROM pg_stats WHERE tablename = 'road'; - attname | inherited | n_distinct | most_common_vals + attname | inherited | n_distinct | most_common_vals ---------+-----------+------------+------------------------------------ name | f | -0.363388 | I- 580 Ramp+ | | | I- 880 Ramp+ diff --git a/doc/src/sgml/planstats.sgml b/doc/src/sgml/planstats.sgml index e7171ffb9b..88cc7df2f9 100644 --- a/doc/src/sgml/planstats.sgml +++ b/doc/src/sgml/planstats.sgml @@ -67,9 +67,9 @@ SELECT relpages, reltuples FROM pg_class WHERE relname = 'tenk1'; not requiring a table scan). If that is different from relpages then reltuples is scaled accordingly to - arrive at a current number-of-rows estimate. In this case the values - are correct so the rows estimate is the same as - reltuples. + arrive at a current number-of-rows estimate. In this case the value of + relpages is up-to-date so the rows estimate is + the same as reltuples. diff --git a/doc/src/sgml/ref/analyze.sgml b/doc/src/sgml/ref/analyze.sgml index d5f2528eb9..7545fa5d86 100644 --- a/doc/src/sgml/ref/analyze.sgml +++ b/doc/src/sgml/ref/analyze.sgml @@ -102,8 +102,9 @@ ANALYZE [ VERBOSE ] [ table [ ( + strategy for read-mostly databases is to run and ANALYZE once a day during a low-usage time of day. + (This will not be sufficient if there is heavy update activity.) @@ -181,11 +182,13 @@ ANALYZE [ VERBOSE ] [ table [ ( ANALYZE will gather statistics twice: once on the rows of the parent table only, and a second time on the rows of the - parent table with all of its children. The autovacuum daemon, however, - will only consider inserts or updates on the parent table when deciding - whether to trigger an automatic analyze. If that table is rarely - inserted into or updated, the inheritance statistics will not be up to date - unless you run ANALYZE manually. + parent table with all of its children. This second set of statistics + is needed when planning queries that traverse the entire inheritance + tree. The autovacuum daemon, however, will only consider inserts or + updates on the parent table itself when deciding whether to trigger an + automatic analyze for that table. If that table is rarely inserted into + or updated, the inheritance statistics will not be up to date unless you + run ANALYZE manually. diff --git a/doc/src/sgml/ref/explain.sgml b/doc/src/sgml/ref/explain.sgml index 3d7d13c0c1..8a9c9defca 100644 --- a/doc/src/sgml/ref/explain.sgml +++ b/doc/src/sgml/ref/explain.sgml @@ -60,11 +60,12 @@ EXPLAIN [ ANALYZE ] [ VERBOSE ] statement The most critical part of the display is the estimated statement execution cost, which is the planner's guess at how long it will take to run the - statement (measured in units of disk page fetches). Actually two numbers - are shown: the start-up time before the first row can be returned, and - the total time to return all the rows. For most queries the total time + statement (measured in cost units that are arbitrary, but conventionally + mean disk page fetches). Actually two numbers + are shown: the start-up cost before the first row can be returned, and + the total cost to return all the rows. For most queries the total cost is what matters, but in contexts such as a subquery in EXISTS, the planner - will choose the smallest start-up time instead of the smallest total time + will choose the smallest start-up cost instead of the smallest total cost (since the executor will stop after getting one row, anyway). Also, if you limit the number of rows to return with a LIMIT clause, the planner makes an appropriate interpolation between the endpoint @@ -72,10 +73,11 @@ EXPLAIN [ ANALYZE ] [ VERBOSE ] statement - The ANALYZE option causes the statement to be actually executed, not only - planned. The total elapsed time expended within each plan node (in - milliseconds) and total number of rows it actually returned are added to - the display. This is useful for seeing whether the planner's estimates + The ANALYZE option causes the statement to be actually + executed, not only planned. Then actual runtime statistics are added to + the display, including the total elapsed time expended within each plan + node (in milliseconds) and the total number of rows it actually returned. + This is useful for seeing whether the planner's estimates are close to reality. @@ -116,8 +118,8 @@ ROLLBACK; ANALYZE - Carry out the command and show the actual run times. This - parameter defaults to FALSE. + Carry out the command and show actual run times and other statistics. + This parameter defaults to FALSE. @@ -154,12 +156,16 @@ ROLLBACK; Include information on buffer usage. Specifically, include the number of shared blocks hits, reads, and writes, the number of local blocks hits, reads, and writes, and the number of temp blocks reads and writes. - Shared blocks, local blocks, and temp blocks contain tables and indexes, - temporary tables and temporary indexes, and disk blocks used in sort and - materialized plans, respectively. The number of blocks shown for an + A hit means that a read was avoided because the block was + found already in cache when needed. + Shared blocks contain data from regular tables and indexes; + local blocks contain data from temporary tables and indexes; + while temp blocks contain short-term working data used in sorts, hashes, + Materialize plan nodes, and similar cases. + The number of blocks shown for an upper-level node includes those used by all its child nodes. In text format, only non-zero values are printed. This parameter may only be - used with ANALYZE parameter. It defaults to + used when ANALYZE is also enabled. It defaults to FALSE. @@ -206,35 +212,43 @@ ROLLBACK; - Notes + Outputs - - There is only sparse documentation on the optimizer's use of cost - information in PostgreSQL. Refer to - for more information. - + + The command's result is a textual description of the plan selected + for the statement, + optionally annotated with execution statistics. + describes the information provided. + + + + + Notes In order to allow the PostgreSQL query planner to make reasonably informed decisions when optimizing - queries, the - statement should be run to record statistics about the distribution - of data within the table. If you have not done this (or if the - statistical distribution of the data in the table has changed - significantly since the last time ANALYZE was - run), the estimated costs are unlikely to conform to the real - properties of the query, and consequently an inferior query plan - might be chosen. + queries, the pg_statistic + data should be up-to-date for all tables used in the query. Normally + the autovacuum daemon will take care + of that automatically. But if a table has recently had substantial + changes in its contents, you might need to do a manual + rather than wait for autovacuum to catch up + with the changes. In order to measure the run-time cost of each node in the execution plan, the current implementation of EXPLAIN - ANALYZE can add considerable profiling overhead to query - execution. As a result, running EXPLAIN ANALYZE + ANALYZE adds profiling overhead to query execution. + As a result, running EXPLAIN ANALYZE on a query can sometimes take significantly longer than executing the query normally. The amount of overhead depends on the nature of - the query. + the query, as well as the platform being used. The worst case occurs + for plan nodes that in themselves require very little time per + execution, and on machines that have relatively slow operating + system calls for obtaining the time of day. @@ -256,10 +270,10 @@ EXPLAIN SELECT * FROM foo; - Here is the same query, with JSON formatting: + Here is the same query, with JSON output formatting: EXPLAIN (FORMAT JSON) SELECT * FROM foo; - QUERY PLAN + QUERY PLAN -------------------------------- [ + { + @@ -295,10 +309,10 @@ EXPLAIN SELECT * FROM foo WHERE i = 4; - Here is the same query, but in YAML output: + Here is the same query, but in YAML format: EXPLAIN (FORMAT YAML) SELECT * FROM foo WHERE i='4'; - QUERY PLAN + QUERY PLAN ------------------------------- - Plan: + Node Type: "Index Scan" + @@ -314,10 +328,10 @@ EXPLAIN (FORMAT YAML) SELECT * FROM foo WHERE i='4'; (1 row) - XML output is left as an exercise to the reader. + XML format is left as an exercise for the reader. - Here is the same plan with costs suppressed: + Here is the same plan with cost estimates suppressed: EXPLAIN (COSTS FALSE) SELECT * FROM foo WHERE i = 4; @@ -357,7 +371,7 @@ PREPARE query(int, int) AS SELECT sum(bar) FROM test EXPLAIN ANALYZE EXECUTE query(100, 200); - QUERY PLAN + QUERY PLAN ------------------------------------------------------------------------------------------------------------------------- HashAggregate (cost=39.53..39.53 rows=1 width=8) (actual time=0.661..0.672 rows=7 loops=1) -> Index Scan using test_pkey on test (cost=0.00..32.97 rows=1311 width=8) (actual time=0.050..0.395 rows=99 loops=1)