Sophie

Sophie

distrib > Mageia > 4 > x86_64 > by-pkgid > 977b9e43ddbf791a68788d984b14383d > files > 1182

postgresql9.3-docs-9.3.9-1.mga4.noarch.rpm

<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>Using EXPLAIN</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 9.3.9 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="Performance Tips"
HREF="performance-tips.html"><LINK
REL="PREVIOUS"
TITLE="Performance Tips"
HREF="performance-tips.html"><LINK
REL="NEXT"
TITLE="Statistics Used by the Planner"
HREF="planner-stats.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2015-06-13T20:07:22"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
><A
HREF="index.html"
>PostgreSQL 9.3.9 Documentation</A
></TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
TITLE="Performance Tips"
HREF="performance-tips.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="performance-tips.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 14. Performance Tips</TD
><TD
WIDTH="20%"
ALIGN="right"
VALIGN="top"
><A
TITLE="Statistics Used by the Planner"
HREF="planner-stats.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="USING-EXPLAIN"
>14.1. Using <TT
CLASS="COMMAND"
>EXPLAIN</TT
></A
></H1
><P
>    <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> devises a <I
CLASS="FIRSTTERM"
>query
    plan</I
> for each query it receives.  Choosing the right
    plan to match the query structure and the properties of the data
    is absolutely critical for good performance, so the system includes
    a complex <I
CLASS="FIRSTTERM"
>planner</I
> that tries to choose good plans.
    You can use the <A
HREF="sql-explain.html"
>EXPLAIN</A
> command
    to see what query plan the planner creates for any query.
    Plan-reading is an art that requires some experience to master,
    but this section attempts to cover the basics.
   </P
><P
>    Examples in this section are drawn from the regression test database
    after doing a <TT
CLASS="COMMAND"
>VACUUM ANALYZE</TT
>, using 9.3 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 <TT
CLASS="COMMAND"
>ANALYZE</TT
>'s statistics are random samples rather
    than exact, and because costs are inherently somewhat platform-dependent.
   </P
><P
>    The examples use <TT
CLASS="COMMAND"
>EXPLAIN</TT
>'s default <SPAN
CLASS="QUOTE"
>"text"</SPAN
> output
    format, which is compact and convenient for humans to read.
    If you want to feed <TT
CLASS="COMMAND"
>EXPLAIN</TT
>'s output to a program for further
    analysis, you should use one of its machine-readable output formats
    (XML, JSON, or YAML) instead.
   </P
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="USING-EXPLAIN-BASICS"
>14.1.1. <TT
CLASS="COMMAND"
>EXPLAIN</TT
> Basics</A
></H2
><P
>    The structure of a query plan is a tree of <I
CLASS="FIRSTTERM"
>plan nodes</I
>.
    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.  There are also non-table row sources, such as <TT
CLASS="LITERAL"
>VALUES</TT
>
    clauses and set-returning functions in <TT
CLASS="LITERAL"
>FROM</TT
>, 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 <TT
CLASS="COMMAND"
>EXPLAIN</TT
> 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.  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.
   </P
><P
>    Here is a trivial example, just to show what the output looks like:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1;

                         QUERY PLAN
-------------------------------------------------------------
 Seq Scan on tenk1  (cost=0.00..458.00 rows=10000 width=244)</PRE
><P>
   </P
><P
>    Since this query has no <TT
CLASS="LITERAL"
>WHERE</TT
> 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):

    <P
></P
></P><UL
><LI
><P
>       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.
      </P
></LI
><LI
><P
>       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 <TT
CLASS="LITERAL"
>LIMIT</TT
> example below).
      </P
></LI
><LI
><P
>       Estimated number of rows output by this plan node.  Again, the node
       is assumed to be run to completion.
      </P
></LI
><LI
><P
>       Estimated average width of rows output by this plan node (in bytes).
      </P
></LI
></UL
><P>
   </P
><P
>    The costs are measured in arbitrary units determined by the planner's
    cost parameters (see <A
HREF="runtime-config-query.html#RUNTIME-CONFIG-QUERY-CONSTANTS"
>Section 18.7.2</A
>).
    Traditional practice is to measure the costs in units of disk page
    fetches; that is, <A
HREF="runtime-config-query.html#GUC-SEQ-PAGE-COST"
>seq_page_cost</A
> is conventionally
    set to <TT
CLASS="LITERAL"
>1.0</TT
> and the other cost parameters are set relative
    to that.  The examples in this section are run with the default cost
    parameters.
   </P
><P
>    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
    result rows to the client, which could be an important
    factor in the real 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.)
   </P
><P
>    The <TT
CLASS="LITERAL"
>rows</TT
> 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
    <TT
CLASS="LITERAL"
>WHERE</TT
>-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.
   </P
><P
>    Returning to our example:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1;

                         QUERY PLAN
-------------------------------------------------------------
 Seq Scan on tenk1  (cost=0.00..458.00 rows=10000 width=244)</PRE
><P>
   </P
><P
>    These numbers are derived very straightforwardly.  If you do:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT relpages, reltuples FROM pg_class WHERE relname = 'tenk1';</PRE
><P>

    you will find that <CODE
CLASS="CLASSNAME"
>tenk1</CODE
> has 358 disk
    pages and 10000 rows.  The estimated cost is computed as (disk pages read *
    <A
HREF="runtime-config-query.html#GUC-SEQ-PAGE-COST"
>seq_page_cost</A
>) + (rows scanned *
    <A
HREF="runtime-config-query.html#GUC-CPU-TUPLE-COST"
>cpu_tuple_cost</A
>).  By default,
    <TT
CLASS="VARNAME"
>seq_page_cost</TT
> is 1.0 and <TT
CLASS="VARNAME"
>cpu_tuple_cost</TT
> is 0.01,
    so the estimated cost is (358 * 1.0) + (10000 * 0.01) = 458.
   </P
><P
>    Now let's modify the query to add a <TT
CLASS="LITERAL"
>WHERE</TT
> condition:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1 WHERE unique1 &lt; 7000;

                         QUERY PLAN
------------------------------------------------------------
 Seq Scan on tenk1  (cost=0.00..483.00 rows=7001 width=244)
   Filter: (unique1 &lt; 7000)</PRE
><P>

    Notice that the <TT
CLASS="COMMAND"
>EXPLAIN</TT
> output shows the <TT
CLASS="LITERAL"
>WHERE</TT
>
    clause being applied as a <SPAN
CLASS="QUOTE"
>"filter"</SPAN
> 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
    <TT
CLASS="LITERAL"
>WHERE</TT
> 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 * <A
HREF="runtime-config-query.html#GUC-CPU-OPERATOR-COST"
>cpu_operator_cost</A
>, to be exact) to reflect the extra CPU
    time spent checking the <TT
CLASS="LITERAL"
>WHERE</TT
> condition.
   </P
><P
>    The actual number of rows this query would select is 7000, but the <TT
CLASS="LITERAL"
>rows</TT
>
    estimate is only approximate.  If you try to duplicate this experiment,
    you will probably get a slightly different estimate; moreover, it can
    change after each <TT
CLASS="COMMAND"
>ANALYZE</TT
> command, because the
    statistics produced by <TT
CLASS="COMMAND"
>ANALYZE</TT
> are taken from a
    randomized sample of the table.
   </P
><P
>    Now, let's make the condition more restrictive:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1 WHERE unique1 &lt; 100;

                                  QUERY PLAN
------------------------------------------------------------------------------
 Bitmap Heap Scan on tenk1  (cost=5.07..229.20 rows=101 width=244)
   Recheck Cond: (unique1 &lt; 100)
   -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..5.04 rows=101 width=0)
         Index Cond: (unique1 &lt; 100)</PRE
><P>

    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 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
    before reading them, to minimize the cost of separate fetches.
    The <SPAN
CLASS="QUOTE"
>"bitmap"</SPAN
> mentioned in the node names is the mechanism that
    does the sorting.)
   </P
><P
>    Now let's add another condition to the <TT
CLASS="LITERAL"
>WHERE</TT
> clause:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1 WHERE unique1 &lt; 100 AND stringu1 = 'xxx';

                                  QUERY PLAN
------------------------------------------------------------------------------
 Bitmap Heap Scan on tenk1  (cost=5.04..229.43 rows=1 width=244)
   Recheck Cond: (unique1 &lt; 100)
   Filter: (stringu1 = 'xxx'::name)
   -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..5.04 rows=101 width=0)
         Index Cond: (unique1 &lt; 100)</PRE
><P>

    The added condition <TT
CLASS="LITERAL"
>stringu1 = 'xxx'</TT
> reduces the
    output row count estimate, but not the cost because we still have to visit
    the same set of rows.  Notice that the <TT
CLASS="LITERAL"
>stringu1</TT
> clause
    cannot be applied as an index condition, since this index is only on
    the <TT
CLASS="LITERAL"
>unique1</TT
> 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.
   </P
><P
>    In some cases the planner will prefer a <SPAN
CLASS="QUOTE"
>"simple"</SPAN
> index scan plan:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1 WHERE unique1 = 42;

                                 QUERY PLAN
-----------------------------------------------------------------------------
 Index Scan using tenk1_unique1 on tenk1  (cost=0.29..8.30 rows=1 width=244)
   Index Cond: (unique1 = 42)</PRE
><P>

    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 <TT
CLASS="LITERAL"
>ORDER BY</TT
> condition
    that matches the index order, because then no extra sorting step is needed
    to satisfy the <TT
CLASS="LITERAL"
>ORDER BY</TT
>.
   </P
><P
>    If there are separate indexes on several of the columns referenced
    in <TT
CLASS="LITERAL"
>WHERE</TT
>, the planner might choose to use an AND or OR
    combination of the indexes:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1 WHERE unique1 &lt; 100 AND unique2 &gt; 9000;

                                     QUERY PLAN
-------------------------------------------------------------------------------------
 Bitmap Heap Scan on tenk1  (cost=25.08..60.21 rows=10 width=244)
   Recheck Cond: ((unique1 &lt; 100) AND (unique2 &gt; 9000))
   -&gt;  BitmapAnd  (cost=25.08..25.08 rows=10 width=0)
         -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..5.04 rows=101 width=0)
               Index Cond: (unique1 &lt; 100)
         -&gt;  Bitmap Index Scan on tenk1_unique2  (cost=0.00..19.78 rows=999 width=0)
               Index Cond: (unique2 &gt; 9000)</PRE
><P>

    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
    a filter.  If you vary the ranges involved you'll see the plan change
    accordingly.
   </P
><P
>    Here is an example showing the effects of <TT
CLASS="LITERAL"
>LIMIT</TT
>:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT * FROM tenk1 WHERE unique1 &lt; 100 AND unique2 &gt; 9000 LIMIT 2;

                                     QUERY PLAN
-------------------------------------------------------------------------------------
 Limit  (cost=0.29..14.48 rows=2 width=244)
   -&gt;  Index Scan using tenk1_unique2 on tenk1  (cost=0.29..71.27 rows=10 width=244)
         Index Cond: (unique2 &gt; 9000)
         Filter: (unique1 &lt; 100)</PRE
><P>
   </P
><P
>    This is the same query as above, but we added a <TT
CLASS="LITERAL"
>LIMIT</TT
> 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.
   </P
><P
>    Let's try joining two tables, using the columns we have been discussing:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT *
FROM tenk1 t1, tenk2 t2
WHERE t1.unique1 &lt; 10 AND t1.unique2 = t2.unique2;

                                      QUERY PLAN
--------------------------------------------------------------------------------------
 Nested Loop  (cost=4.65..118.62 rows=10 width=488)
   -&gt;  Bitmap Heap Scan on tenk1 t1  (cost=4.36..39.47 rows=10 width=244)
         Recheck Cond: (unique1 &lt; 10)
         -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..4.36 rows=10 width=0)
               Index Cond: (unique1 &lt; 10)
   -&gt;  Index Scan using tenk2_unique2 on tenk2 t2  (cost=0.29..7.91 rows=1 width=244)
         Index Cond: (unique2 = t1.unique2)</PRE
><P>
   </P
><P
>    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 <SPAN
CLASS="QUOTE"
>"outer"</SPAN
>, child
    is a bitmap scan similar to those we saw before.  Its cost and row count
    are the same as we'd get from <TT
CLASS="LITERAL"
>SELECT ... WHERE unique1 &lt; 10</TT
>
    because we are
    applying the <TT
CLASS="LITERAL"
>WHERE</TT
> clause <TT
CLASS="LITERAL"
>unique1 &lt; 10</TT
>
    at that node.
    The <TT
CLASS="LITERAL"
>t1.unique2 = t2.unique2</TT
> clause is not relevant yet,
    so it doesn't affect the row count of the outer scan.  The nested-loop
    join node will run its second,
    or <SPAN
CLASS="QUOTE"
>"inner"</SPAN
> 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 <TT
CLASS="LITERAL"
>t1.unique2</TT
> value from the outer row is available,
    so we get a plan and costs similar to what we saw above for a simple
    <TT
CLASS="LITERAL"
>SELECT ... WHERE t2.unique2 = <TT
CLASS="REPLACEABLE"
><I
>constant</I
></TT
></TT
> 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
    index scans on <TT
CLASS="LITERAL"
>t2</TT
>.)  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 (10 * 7.87,
    here), plus a little CPU time for join processing.
   </P
><P
>    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
    there can be additional <TT
CLASS="LITERAL"
>WHERE</TT
> clauses that mention both tables
    and so can only be applied at the join point, not to either input scan.
    Here's an example:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT *
FROM tenk1 t1, tenk2 t2
WHERE t1.unique1 &lt; 10 AND t2.unique2 &lt; 10 AND t1.hundred &lt; t2.hundred;

                                         QUERY PLAN
---------------------------------------------------------------------------------------------
 Nested Loop  (cost=4.65..49.46 rows=33 width=488)
   Join Filter: (t1.hundred &lt; t2.hundred)
   -&gt;  Bitmap Heap Scan on tenk1 t1  (cost=4.36..39.47 rows=10 width=244)
         Recheck Cond: (unique1 &lt; 10)
         -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..4.36 rows=10 width=0)
               Index Cond: (unique1 &lt; 10)
   -&gt;  Materialize  (cost=0.29..8.51 rows=10 width=244)
         -&gt;  Index Scan using tenk2_unique2 on tenk2 t2  (cost=0.29..8.46 rows=10 width=244)
               Index Cond: (unique2 &lt; 10)</PRE
><P>

    The condition <TT
CLASS="LITERAL"
>t1.hundred &lt; t2.hundred</TT
> can't be
    tested in the <TT
CLASS="LITERAL"
>tenk2_unique2</TT
> 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.
   </P
><P
>    Notice that here the planner has chosen to <SPAN
CLASS="QUOTE"
>"materialize"</SPAN
> the inner
    relation of the join, by putting a Materialize plan node atop it.  This
    means that the <TT
CLASS="LITERAL"
>t2</TT
> indexscan will be done just once, even
    though the nested-loop join node needs to read that data ten times, once
    for each row from the outer relation.  The Materialize node saves the data
    in memory as it's read, and then returns the data from memory on each
    subsequent pass.
   </P
><P
>    When dealing with outer joins, you might see join plan nodes with both
    <SPAN
CLASS="QUOTE"
>"Join Filter"</SPAN
> and plain <SPAN
CLASS="QUOTE"
>"Filter"</SPAN
> conditions attached.
    Join Filter conditions come from the outer join's <TT
CLASS="LITERAL"
>ON</TT
> 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.
   </P
><P
>    If we change the query's selectivity a bit, we might get a very different
    join plan:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT *
FROM tenk1 t1, tenk2 t2
WHERE t1.unique1 &lt; 100 AND t1.unique2 = t2.unique2;

                                        QUERY PLAN
------------------------------------------------------------------------------------------
 Hash Join  (cost=230.47..713.98 rows=101 width=488)
   Hash Cond: (t2.unique2 = t1.unique2)
   -&gt;  Seq Scan on tenk2 t2  (cost=0.00..445.00 rows=10000 width=244)
   -&gt;  Hash  (cost=229.20..229.20 rows=101 width=244)
         -&gt;  Bitmap Heap Scan on tenk1 t1  (cost=5.07..229.20 rows=101 width=244)
               Recheck Cond: (unique1 &lt; 100)
               -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..5.04 rows=101 width=0)
                     Index Cond: (unique1 &lt; 100)</PRE
><P>
   </P
><P
>    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 <TT
CLASS="LITERAL"
>tenk1</TT
> 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.
   </P
><P
>    Another possible type of join is a merge join, illustrated here:

</P><PRE
CLASS="SCREEN"
>EXPLAIN SELECT *
FROM tenk1 t1, onek t2
WHERE t1.unique1 &lt; 100 AND t1.unique2 = t2.unique2;

                                        QUERY PLAN
------------------------------------------------------------------------------------------
 Merge Join  (cost=198.11..268.19 rows=10 width=488)
   Merge Cond: (t1.unique2 = t2.unique2)
   -&gt;  Index Scan using tenk1_unique2 on tenk1 t1  (cost=0.29..656.28 rows=101 width=244)
         Filter: (unique1 &lt; 100)
   -&gt;  Sort  (cost=197.83..200.33 rows=1000 width=244)
         Sort Key: t2.unique2
         -&gt;  Seq Scan on onek t2  (cost=0.00..148.00 rows=1000 width=244)</PRE
><P>
   </P
><P
>    Merge join requires its input data to be sorted on the join keys.  In this
    plan the <TT
CLASS="LITERAL"
>tenk1</TT
> 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 <TT
CLASS="LITERAL"
>onek</TT
>, because there are many more rows to be visited in
    that table.
    (Sequential-scan-and-sort frequently beats an index scan for sorting many rows,
    because of the nonsequential disk access required by the index scan.)
   </P
><P
>    One way to look at variant plans is to force the planner to disregard
    whatever strategy it thought was the cheapest, using the enable/disable
    flags described in <A
HREF="runtime-config-query.html#RUNTIME-CONFIG-QUERY-ENABLE"
>Section 18.7.1</A
>.
    (This is a crude tool, but useful.  See
    also <A
HREF="explicit-joins.html"
>Section 14.3</A
>.)
    For example, if we're unconvinced that sequential-scan-and-sort is the best way to
    deal with table <TT
CLASS="LITERAL"
>onek</TT
> in the previous example, we could try

</P><PRE
CLASS="SCREEN"
>SET enable_sort = off;

EXPLAIN SELECT *
FROM tenk1 t1, onek t2
WHERE t1.unique1 &lt; 100 AND t1.unique2 = t2.unique2;

                                        QUERY PLAN
------------------------------------------------------------------------------------------
 Merge Join  (cost=0.56..292.65 rows=10 width=488)
   Merge Cond: (t1.unique2 = t2.unique2)
   -&gt;  Index Scan using tenk1_unique2 on tenk1 t1  (cost=0.29..656.28 rows=101 width=244)
         Filter: (unique1 &lt; 100)
   -&gt;  Index Scan using onek_unique2 on onek t2  (cost=0.28..224.79 rows=1000 width=244)</PRE
><P>

    which shows that the planner thinks that sorting <TT
CLASS="LITERAL"
>onek</TT
> by
    index-scanning is about 12% more expensive than sequential-scan-and-sort.
    Of course, the next question is whether it's right about that.
    We can investigate that using <TT
CLASS="COMMAND"
>EXPLAIN ANALYZE</TT
>, as discussed
    below.
   </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="USING-EXPLAIN-ANALYZE"
>14.1.2. <TT
CLASS="COMMAND"
>EXPLAIN ANALYZE</TT
></A
></H2
><P
>    It is possible to check the accuracy of the planner's estimates
    by using <TT
CLASS="COMMAND"
>EXPLAIN</TT
>'s <TT
CLASS="LITERAL"
>ANALYZE</TT
> option.  With this
    option, <TT
CLASS="COMMAND"
>EXPLAIN</TT
> 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 <TT
CLASS="COMMAND"
>EXPLAIN</TT
>
    shows.  For example, we might get a result like this:

</P><PRE
CLASS="SCREEN"
>EXPLAIN ANALYZE SELECT *
FROM tenk1 t1, tenk2 t2
WHERE t1.unique1 &lt; 10 AND t1.unique2 = t2.unique2;

                                                           QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------
 Nested Loop  (cost=4.65..118.62 rows=10 width=488) (actual time=0.128..0.377 rows=10 loops=1)
   -&gt;  Bitmap Heap Scan on tenk1 t1  (cost=4.36..39.47 rows=10 width=244) (actual time=0.057..0.121 rows=10 loops=1)
         Recheck Cond: (unique1 &lt; 10)
         -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..4.36 rows=10 width=0) (actual time=0.024..0.024 rows=10 loops=1)
               Index Cond: (unique1 &lt; 10)
   -&gt;  Index Scan using tenk2_unique2 on tenk2 t2  (cost=0.29..7.91 rows=1 width=244) (actual time=0.021..0.022 rows=1 loops=10)
         Index Cond: (unique2 = t1.unique2)
 Total runtime: 0.501 ms</PRE
><P>

    Note that the <SPAN
CLASS="QUOTE"
>"actual time"</SPAN
> values are in milliseconds of
    real time, whereas the <TT
CLASS="LITERAL"
>cost</TT
> estimates are expressed in
    arbitrary units; so they are unlikely to match up.
    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.
   </P
><P
>    In some query plans, it is possible for a subplan node to be executed more
    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
    <TT
CLASS="LITERAL"
>loops</TT
> 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 <TT
CLASS="LITERAL"
>loops</TT
> value to get the total time actually spent in
    the node.  In the above example, we spent a total of 0.220 milliseconds
    executing the index scans on <TT
CLASS="LITERAL"
>tenk2</TT
>.
   </P
><P
>    In some cases <TT
CLASS="COMMAND"
>EXPLAIN ANALYZE</TT
> shows additional execution
    statistics beyond the plan node execution times and row counts.
    For example, Sort and Hash nodes provide extra information:

</P><PRE
CLASS="SCREEN"
>EXPLAIN ANALYZE SELECT *
FROM tenk1 t1, tenk2 t2
WHERE t1.unique1 &lt; 100 AND t1.unique2 = t2.unique2 ORDER BY t1.fivethous;

                                                                 QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------------
 Sort  (cost=717.34..717.59 rows=101 width=488) (actual time=7.761..7.774 rows=100 loops=1)
   Sort Key: t1.fivethous
   Sort Method: quicksort  Memory: 77kB
   -&gt;  Hash Join  (cost=230.47..713.98 rows=101 width=488) (actual time=0.711..7.427 rows=100 loops=1)
         Hash Cond: (t2.unique2 = t1.unique2)
         -&gt;  Seq Scan on tenk2 t2  (cost=0.00..445.00 rows=10000 width=244) (actual time=0.007..2.583 rows=10000 loops=1)
         -&gt;  Hash  (cost=229.20..229.20 rows=101 width=244) (actual time=0.659..0.659 rows=100 loops=1)
               Buckets: 1024  Batches: 1  Memory Usage: 28kB
               -&gt;  Bitmap Heap Scan on tenk1 t1  (cost=5.07..229.20 rows=101 width=244) (actual time=0.080..0.526 rows=100 loops=1)
                     Recheck Cond: (unique1 &lt; 100)
                     -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..5.04 rows=101 width=0) (actual time=0.049..0.049 rows=100 loops=1)
                           Index Cond: (unique1 &lt; 100)
 Total runtime: 8.008 ms</PRE
><P>

    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.)
   </P
><P
>    Another type of extra information is the number of rows removed by a
    filter condition:

</P><PRE
CLASS="SCREEN"
>EXPLAIN ANALYZE SELECT * FROM tenk1 WHERE ten &lt; 7;

                                               QUERY PLAN
---------------------------------------------------------------------------------------------------------
 Seq Scan on tenk1  (cost=0.00..483.00 rows=7000 width=244) (actual time=0.016..5.107 rows=7000 loops=1)
   Filter: (ten &lt; 7)
   Rows Removed by Filter: 3000
 Total runtime: 5.905 ms</PRE
><P>

    These counts can be particularly valuable for filter conditions applied at
    join nodes.  The <SPAN
CLASS="QUOTE"
>"Rows Removed"</SPAN
> 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.
   </P
><P
>    A case similar to filter conditions occurs with <SPAN
CLASS="QUOTE"
>"lossy"</SPAN
>
    index scans.  For example, consider this search for polygons containing a
    specific point:

</P><PRE
CLASS="SCREEN"
>EXPLAIN ANALYZE SELECT * FROM polygon_tbl WHERE f1 @&gt; polygon '(0.5,2.0)';

                                              QUERY PLAN
------------------------------------------------------------------------------------------------------
 Seq Scan on polygon_tbl  (cost=0.00..1.05 rows=1 width=32) (actual time=0.044..0.044 rows=0 loops=1)
   Filter: (f1 @&gt; '((0.5,2))'::polygon)
   Rows Removed by Filter: 4
 Total runtime: 0.083 ms</PRE
><P>

    The planner thinks (quite correctly) that this sample table is too small
    to bother with an index scan, so we have a plain sequential scan in which
    all the rows got rejected by the filter condition.  But if we force an
    index scan to be used, we see:

</P><PRE
CLASS="SCREEN"
>SET enable_seqscan TO off;

EXPLAIN ANALYZE SELECT * FROM polygon_tbl WHERE f1 @&gt; polygon '(0.5,2.0)';

                                                        QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------
 Index Scan using gpolygonind on polygon_tbl  (cost=0.13..8.15 rows=1 width=32) (actual time=0.062..0.062 rows=0 loops=1)
   Index Cond: (f1 @&gt; '((0.5,2))'::polygon)
   Rows Removed by Index Recheck: 1
 Total runtime: 0.144 ms</PRE
><P>

    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 <SPAN
CLASS="QUOTE"
>"lossy"</SPAN
> 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.
   </P
><P
>    <TT
CLASS="COMMAND"
>EXPLAIN</TT
> has a <TT
CLASS="LITERAL"
>BUFFERS</TT
> option that can be used with
    <TT
CLASS="LITERAL"
>ANALYZE</TT
> to get even more run time statistics:

</P><PRE
CLASS="SCREEN"
>EXPLAIN (ANALYZE, BUFFERS) SELECT * FROM tenk1 WHERE unique1 &lt; 100 AND unique2 &gt; 9000;

                                                           QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------
 Bitmap Heap Scan on tenk1  (cost=25.08..60.21 rows=10 width=244) (actual time=0.323..0.342 rows=10 loops=1)
   Recheck Cond: ((unique1 &lt; 100) AND (unique2 &gt; 9000))
   Buffers: shared hit=15
   -&gt;  BitmapAnd  (cost=25.08..25.08 rows=10 width=0) (actual time=0.309..0.309 rows=0 loops=1)
         Buffers: shared hit=7
         -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..5.04 rows=101 width=0) (actual time=0.043..0.043 rows=100 loops=1)
               Index Cond: (unique1 &lt; 100)
               Buffers: shared hit=2
         -&gt;  Bitmap Index Scan on tenk1_unique2  (cost=0.00..19.78 rows=999 width=0) (actual time=0.227..0.227 rows=999 loops=1)
               Index Cond: (unique2 &gt; 9000)
               Buffers: shared hit=5
 Total runtime: 0.423 ms</PRE
><P>

    The numbers provided by <TT
CLASS="LITERAL"
>BUFFERS</TT
> help to identify which parts
    of the query are the most I/O-intensive.
   </P
><P
>    Keep in mind that because <TT
CLASS="COMMAND"
>EXPLAIN ANALYZE</TT
> 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 <TT
CLASS="COMMAND"
>EXPLAIN</TT
> data.  If you want to analyze a
    data-modifying query without changing your tables, you can
    roll the command back afterwards, for example:

</P><PRE
CLASS="SCREEN"
>BEGIN;

EXPLAIN ANALYZE UPDATE tenk1 SET hundred = hundred + 1 WHERE unique1 &lt; 100;

                                                           QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------
 Update on tenk1  (cost=5.07..229.46 rows=101 width=250) (actual time=14.628..14.628 rows=0 loops=1)
   -&gt;  Bitmap Heap Scan on tenk1  (cost=5.07..229.46 rows=101 width=250) (actual time=0.101..0.439 rows=100 loops=1)
         Recheck Cond: (unique1 &lt; 100)
         -&gt;  Bitmap Index Scan on tenk1_unique1  (cost=0.00..5.04 rows=101 width=0) (actual time=0.043..0.043 rows=100 loops=1)
               Index Cond: (unique1 &lt; 100)
 Total runtime: 14.727 ms

ROLLBACK;</PRE
><P>
   </P
><P
>    As seen in this example, when the query is an <TT
CLASS="COMMAND"
>INSERT</TT
>,
    <TT
CLASS="COMMAND"
>UPDATE</TT
>, or <TT
CLASS="COMMAND"
>DELETE</TT
> 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 run time (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.
   </P
><P
>    The <TT
CLASS="LITERAL"
>Total runtime</TT
> shown by <TT
CLASS="COMMAND"
>EXPLAIN
    ANALYZE</TT
> 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 <TT
CLASS="LITERAL"
>BEFORE</TT
> triggers, if any, is included in
    the time for the related Insert, Update, or Delete node; but time
    spent executing <TT
CLASS="LITERAL"
>AFTER</TT
> triggers is not counted there because
    <TT
CLASS="LITERAL"
>AFTER</TT
> triggers are fired after completion of the whole plan.
    The total time spent in each trigger
    (either <TT
CLASS="LITERAL"
>BEFORE</TT
> or <TT
CLASS="LITERAL"
>AFTER</TT
>) 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
    <TT
CLASS="COMMAND"
>EXPLAIN ANALYZE</TT
>.
   </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="USING-EXPLAIN-CAVEATS"
>14.1.3. Caveats</A
></H2
><P
>    There are two significant ways in which run times measured by
    <TT
CLASS="COMMAND"
>EXPLAIN ANALYZE</TT
> 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 conversion costs are not included.
    Second, the measurement overhead added by <TT
CLASS="COMMAND"
>EXPLAIN
    ANALYZE</TT
> can be significant, especially on machines with slow
    <CODE
CLASS="FUNCTION"
>gettimeofday()</CODE
> operating-system calls. You can use the
    <A
HREF="pgtesttiming.html"
><SPAN
CLASS="APPLICATION"
>pg_test_timing</SPAN
></A
> tool to measure the overhead of timing
    on your system.
   </P
><P
>    <TT
CLASS="COMMAND"
>EXPLAIN</TT
> 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
    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.  (We saw this happening in the
    <TT
CLASS="LITERAL"
>polygon_tbl</TT
> example above.)
   </P
><P
>    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 <TT
CLASS="LITERAL"
>LIMIT</TT
> or similar
    effect.  For example, in the <TT
CLASS="LITERAL"
>LIMIT</TT
> query we used before,

</P><PRE
CLASS="SCREEN"
>EXPLAIN ANALYZE SELECT * FROM tenk1 WHERE unique1 &lt; 100 AND unique2 &gt; 9000 LIMIT 2;

                                                          QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=0.29..14.71 rows=2 width=244) (actual time=0.177..0.249 rows=2 loops=1)
   -&gt;  Index Scan using tenk1_unique2 on tenk1  (cost=0.29..72.42 rows=10 width=244) (actual time=0.174..0.244 rows=2 loops=1)
         Index Cond: (unique2 &gt; 9000)
         Filter: (unique1 &lt; 100)
         Rows Removed by Filter: 287
 Total runtime: 0.336 ms</PRE
><P>

    the estimated cost and row count 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 row count is only 2 and
    the run time 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.
   </P
><P
>    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 <TT
CLASS="LITERAL"
>LIMIT</TT
>.
    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.  <TT
CLASS="COMMAND"
>EXPLAIN ANALYZE</TT
> 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 row count
    for the inner child plan node can be significantly larger than the number
    of rows that are actually in the inner relation.
   </P
><P
>    BitmapAnd and BitmapOr nodes always report their actual row counts as zero,
    due to implementation limitations.
   </P
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="performance-tips.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="planner-stats.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Performance Tips</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="performance-tips.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Statistics Used by the Planner</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>