EnterpriseDB devises a query
plan for each query it is given. Choosing the right
plan to match the query structure and the properties of the data
is absolutely critical for good performance. You can use the
EXPLAIN command
to see what query plan the system creates for any query.
Plan-reading is an art that deserves an extensive tutorial, which
this is not; but here is some basic information.
The numbers that are currently quoted by EXPLAIN are:
Estimated start-up cost (Time expended before output scan can start,
e.g., time to do the sorting in a sort node.)
Estimated total cost (If all rows were to be retrieved, which they may not
be: a query with a LIMIT clause will stop short of paying the total cost,
for example.)
Estimated number of rows output by this plan node (Again, only if
executed to completion)
Estimated average width (in bytes) of rows output by this plan
node
The costs are measured in units of disk page fetches. (CPU effort
estimates are converted into disk-page units using some
fairly arbitrary fudge factors. If you want to experiment with these
factors, see the list of run-time configuration parameters in
Section 30.4.4.)
It's important to note 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/optimizer cares about.
In particular, the cost does not consider the time spent transmitting
result rows to the frontend, which could be a pretty dominant
factor in the true elapsed time; but the planner ignores it because
it cannot change it by altering the plan. (Every correct plan will
output the same row set, we trust.)
Rows output is a little tricky because it is not the
number of rows
processed/scanned by the query, it is usually less, reflecting the
estimated selectivity of any WHERE-clause conditions that are being
applied at this node. Ideally the top-level rows estimate will
approximate the number of rows actually returned, updated, or deleted
by the query.
Here are some examples (using the regression test database after a
VACUUM ANALYZE, and 7.3 development sources):
EXPLAIN SELECT * FROM tenk1;
QUERY PLAN
-------------------------------------------------------------
Seq Scan on tenk1 (cost=0.00..333.00 rows=10000 width=148)
This is about as straightforward as it gets. If you do
SELECT * FROM pg_class WHERE relname = 'tenk1';
you will find out that tenk1
has 233 disk
pages and 10000 rows. So the cost is estimated at 233 page
reads, defined as costing 1.0 apiece, plus 10000 * cpu_tuple_cost which is
currently 0.01 (try SHOW cpu_tuple_cost).
Now let's modify the query to add a WHERE condition:
EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 1000;
QUERY PLAN
------------------------------------------------------------
Seq Scan on tenk1 (cost=0.00..358.00 rows=1033 width=148)
Filter: (unique1 < 1000)
The estimate of output rows has gone down 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 to reflect the extra CPU
time spent checking the WHERE condition.
The actual number of rows this query would select is 1000, but the
estimate is only approximate. If you try to duplicate this experiment,
you will probably get a slightly different estimate; moreover, it will
change after each ANALYZE command, because the
statistics produced by ANALYZE are taken from a
randomized sample of the table.
Modify the query to restrict the condition even more:
EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 50;
QUERY PLAN
-------------------------------------------------------------------------------
Index Scan using tenk1_unique1 on tenk1 (cost=0.00..179.33 rows=49 width=148)
Index Cond: (unique1 < 50)
and you will see that if we make the WHERE condition selective
enough, the planner will
eventually decide that an index scan is cheaper than a sequential scan.
This plan will only have to visit 50 rows because of the index,
so it wins despite the fact that each individual fetch is more expensive
than reading a whole disk page sequentially.
Add another condition to the WHERE clause:
EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 50 AND stringu1 = 'xxx';
QUERY PLAN
-------------------------------------------------------------------------------
Index Scan using tenk1_unique1 on tenk1 (cost=0.00..179.45 rows=1 width=148)
Index Cond: (unique1 < 50)
Filter: (stringu1 = 'xxx'::name)
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
the rows retrieved by the index. Thus the cost has actually gone up
a little bit to reflect this extra checking.
Let's try joining two tables, using the columns we have been discussing:
EXPLAIN SELECT * FROM tenk1 t1, tenk2 t2 WHERE t1.unique1 < 50 AND t1.unique2 = t2.unique2;
QUERY PLAN
----------------------------------------------------------------------------
Nested Loop (cost=0.00..327.02 rows=49 width=296)
-> Index Scan using tenk1_unique1 on tenk1 t1
(cost=0.00..179.33 rows=49 width=148)
Index Cond: (unique1 < 50)
-> Index Scan using tenk2_unique2 on tenk2 t2
(cost=0.00..3.01 rows=1 width=148)
Index Cond: ("outer".unique2 = t2.unique2)
In this nested-loop join, the outer scan is the same index scan we had
in the example before last, and so its cost and row count are the same
because we are applying the WHERE clause unique1 < 50 at that node.
The t1.unique2 = t2.unique2 clause is not relevant yet, so it doesn't
affect row count of the outer scan. For the inner scan, the unique2 value of the
current
outer-scan row is plugged into the inner index scan
to produce an index condition like
t2.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 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 (49 * 3.01, 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 general, because
in general you can have 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.
One way to look at variant plans is to force the planner to disregard
whatever strategy it thought was the winner, using the enable/disable
flags for each plan type. (This is a crude tool, but useful. See
also Section 13.4.)
SET enable_nestloop = off;
EXPLAIN SELECT * FROM tenk1 t1, tenk2 t2 WHERE t1.unique1 < 50 AND t1.unique2 = t2.unique2;
QUERY PLAN
--------------------------------------------------------------------------
Hash Join (cost=179.45..563.06 rows=49 width=296)
Hash Cond: ("outer".unique2 = "inner".unique2)
-> Seq Scan on tenk2 t2 (cost=0.00..333.00 rows=10000 width=148)
-> Hash (cost=179.33..179.33 rows=49 width=148)
-> Index Scan using tenk1_unique1 on tenk1 t1
(cost=0.00..179.33 rows=49 width=148)
Index Cond: (unique1 < 50)
This plan proposes to extract the 50 interesting rows of tenk1
using ye same olde 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 at each tenk2
row.
The cost to read tenk1
and set up the hash table is entirely start-up
cost for the hash join, since we won't get any rows out 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 179.33;
the hash table setup is only done once in this plan type.
It is possible to check on 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:
EXPLAIN ANALYZE SELECT * FROM tenk1 t1, tenk2 t2 WHERE t1.unique1 < 50 AND t1.unique2 = t2.unique2;
QUERY PLAN
-------------------------------------------------------------------------------
Nested Loop (cost=0.00..327.02 rows=49 width=296)
(actual time=1.181..29.822 rows=50 loops=1)
-> Index Scan using tenk1_unique1 on tenk1 t1
(cost=0.00..179.33 rows=49 width=148)
(actual time=0.630..8.917 rows=50 loops=1)
Index Cond: (unique1 < 50)
-> Index Scan using tenk2_unique2 on tenk2 t2
(cost=0.00..3.01 rows=1 width=148)
(actual time=0.295..0.324 rows=1 loops=50)
Index Cond: ("outer".unique2 = t2.unique2)
Total runtime: 31.604 ms
Note that the "actual time" values are in milliseconds of
real time, whereas the "cost" estimates are expressed in
arbitrary units of disk fetches; so they are unlikely to match up.
The thing to pay attention to is the ratios.
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
"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 Total runtime shown by EXPLAIN ANALYZE includes
executor start-up and shut-down time, as well as time spent processing
the result rows. It does not include parsing, rewriting, or planning
time. For a SELECT query, the total run time will normally be just a
little larger than the total time reported for the top-level plan node.
For INSERT, UPDATE, and DELETE commands, the total run time may be
considerably larger, because it includes the time spent processing the
result rows. In these commands, the time for the top plan node
essentially is the time spent computing the new rows and/or locating
the old ones, but it doesn't include the time spent making the changes.
It is worth noting that EXPLAIN results should not be extrapolated
to situations other than the one you are actually testing; for example,
results on a toy-sized table can't be assumed to apply to large tables.
The planner's cost estimates are not linear and so it may well choose
a different plan for a larger or smaller table. An extreme example
is that on a table that only occupies one disk page, you'll nearly
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.