Create a third option named "partition" for constraint_exclusion, and make it

the default.  This setting enables constraint exclusion checks only for
appendrel members (ie, inheritance children and UNION ALL arms), which are
the cases in which constraint exclusion is most likely to be useful.  Avoiding
the overhead for simple queries that are unlikely to benefit should bring
the cost down to the point where this is a reasonable default setting.
Per today's discussion.
This commit is contained in:
Tom Lane 2009-01-07 22:40:49 +00:00
parent 12dcf7bb75
commit 445ce15702
7 changed files with 92 additions and 45 deletions

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.202 2009/01/07 12:21:47 mha Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.203 2009/01/07 22:40:48 tgl Exp $ -->
<chapter Id="runtime-config"> <chapter Id="runtime-config">
<title>Server Configuration</title> <title>Server Configuration</title>
@ -2145,7 +2145,7 @@ archive_command = 'copy "%p" "C:\\server\\archivedir\\%f"' # Windows
</varlistentry> </varlistentry>
<varlistentry id="guc-constraint-exclusion" xreflabel="constraint_exclusion"> <varlistentry id="guc-constraint-exclusion" xreflabel="constraint_exclusion">
<term><varname>constraint_exclusion</varname> (<type>boolean</type>)</term> <term><varname>constraint_exclusion</varname> (<type>enum</type>)</term>
<indexterm> <indexterm>
<primary>constraint exclusion</primary> <primary>constraint exclusion</primary>
</indexterm> </indexterm>
@ -2155,14 +2155,20 @@ archive_command = 'copy "%p" "C:\\server\\archivedir\\%f"' # Windows
<listitem> <listitem>
<para> <para>
Enables or disables the query planner's use of table constraints to Enables or disables the query planner's use of table constraints to
optimize queries. The default is <literal>off</>. optimize queries.
The allowed values of <varname>constraint_exclusion</> are
<literal>on</> (examine constraints for all tables),
<literal>off</> (never examine constraints), and
<literal>partition</> (examine constraints only for inheritance child
tables and <literal>UNION ALL</> subqueries).
<literal>partition</> is the default setting.
</para> </para>
<para> <para>
When this parameter is <literal>on</>, the planner compares When this parameter allows it for a particular table, the planner
query conditions with table <literal>CHECK</> constraints, and compares query conditions with the table's <literal>CHECK</>
omits scanning tables for which the conditions contradict the constraints, and omits scanning tables for which the conditions
constraints. For example: contradict the constraints. For example:
<programlisting> <programlisting>
CREATE TABLE parent(key integer, ...); CREATE TABLE parent(key integer, ...);
@ -2179,17 +2185,17 @@ SELECT * FROM parent WHERE key = 2400;
</para> </para>
<para> <para>
Currently, <varname>constraint_exclusion</> is disabled by Currently, constraint exclusion is enabled by default
default because the constraint checks are relatively only for cases that are often used to implement table partitioning.
expensive, and in many circumstances will yield no savings. Turning it on for all tables imposes extra planning overhead that is
It is recommended to turn this on only if you are actually quite noticeable on simple queries, and most often will yield no
using partitioned tables designed to take advantage of the benefit for simple queries. If you have no partitioned tables
feature. you might prefer to turn it off entirely.
</para> </para>
<para> <para>
Refer to <xref linkend="ddl-partitioning"> for more information Refer to <xref linkend="ddl-partitioning-constraint-exclusion"> for
on using constraint exclusion and partitioning. more information on using constraint exclusion and partitioning.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/ddl.sgml,v 1.83 2008/09/08 00:47:40 tgl Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/ddl.sgml,v 1.84 2009/01/07 22:40:49 tgl Exp $ -->
<chapter id="ddl"> <chapter id="ddl">
<title>Data Definition</title> <title>Data Definition</title>
@ -2394,9 +2394,9 @@ CHECK ( outletID BETWEEN 200 AND 300 )
<listitem> <listitem>
<para> <para>
Ensure that the <xref linkend="guc-constraint-exclusion"> Ensure that the <xref linkend="guc-constraint-exclusion">
configuration configuration parameter is not disabled in
parameter is enabled in <filename>postgresql.conf</>. Without <filename>postgresql.conf</>.
this, queries will not be optimized as desired. If it is, queries will not be optimized as desired.
</para> </para>
</listitem> </listitem>
@ -2698,7 +2698,7 @@ SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
<para> <para>
You can use the <command>EXPLAIN</> command to show the difference You can use the <command>EXPLAIN</> command to show the difference
between a plan with <varname>constraint_exclusion</> on and a plan between a plan with <varname>constraint_exclusion</> on and a plan
with it off. A typical default plan for this type of table setup is: with it off. A typical unoptimized plan for this type of table setup is:
<programlisting> <programlisting>
SET constraint_exclusion = off; SET constraint_exclusion = off;
@ -2725,7 +2725,7 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
full-table sequential scans, but the point here is that there full-table sequential scans, but the point here is that there
is no need to scan the older partitions at all to answer this query. is no need to scan the older partitions at all to answer this query.
When we enable constraint exclusion, we get a significantly When we enable constraint exclusion, we get a significantly
reduced plan that will deliver the same answer: cheaper plan that will deliver the same answer:
<programlisting> <programlisting>
SET constraint_exclusion = on; SET constraint_exclusion = on;
@ -2751,6 +2751,17 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
be helpful in the latter case but not the former. be helpful in the latter case but not the former.
</para> </para>
<para>
The default (and recommended) setting of
<xref linkend="guc-constraint-exclusion"> is actually neither
<literal>on</> nor <literal>off</>, but an intermediate setting
called <literal>partition</>, which causes the technique to be
applied only to queries that are likely to be working on partitioned
tables. The <literal>on</> setting causes the planner to examine
<literal>CHECK</> constraints in all queries, even simple ones that
are unlikely to benefit.
</para>
</sect2> </sect2>
<sect2 id="ddl-partitioning-alternatives"> <sect2 id="ddl-partitioning-alternatives">

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/textsearch.sgml,v 1.46 2008/10/17 18:05:19 teodor Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/textsearch.sgml,v 1.47 2009/01/07 22:40:49 tgl Exp $ -->
<chapter id="textsearch"> <chapter id="textsearch">
<title id="textsearch-title">Full Text Search</title> <title id="textsearch-title">Full Text Search</title>
@ -3254,8 +3254,8 @@ SELECT plainto_tsquery('supernovae stars');
<para> <para>
Partitioning of big collections and the proper use of GiST and GIN indexes Partitioning of big collections and the proper use of GiST and GIN indexes
allows the implementation of very fast searches with online update. allows the implementation of very fast searches with online update.
Partitioning can be done at the database level using table inheritance Partitioning can be done at the database level using table inheritance,
and <varname>constraint_exclusion</>, or by distributing documents over or by distributing documents over
servers and collecting search results using the <filename>contrib/dblink</> servers and collecting search results using the <filename>contrib/dblink</>
extension module. The latter is possible because ranking functions use extension module. The latter is possible because ranking functions use
only local information. only local information.

View File

@ -9,7 +9,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/optimizer/util/plancat.c,v 1.153 2009/01/01 17:23:45 momjian Exp $ * $PostgreSQL: pgsql/src/backend/optimizer/util/plancat.c,v 1.154 2009/01/07 22:40:49 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
@ -27,6 +27,7 @@
#include "nodes/makefuncs.h" #include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h" #include "nodes/nodeFuncs.h"
#include "optimizer/clauses.h" #include "optimizer/clauses.h"
#include "optimizer/cost.h"
#include "optimizer/plancat.h" #include "optimizer/plancat.h"
#include "optimizer/predtest.h" #include "optimizer/predtest.h"
#include "optimizer/prep.h" #include "optimizer/prep.h"
@ -43,7 +44,7 @@
/* GUC parameter */ /* GUC parameter */
bool constraint_exclusion = false; int constraint_exclusion = CONSTRAINT_EXCLUSION_PARTITION;
/* Hook for plugins to get control in get_relation_info() */ /* Hook for plugins to get control in get_relation_info() */
get_relation_info_hook_type get_relation_info_hook = NULL; get_relation_info_hook_type get_relation_info_hook = NULL;
@ -561,8 +562,9 @@ get_relation_constraints(PlannerInfo *root,
* self-inconsistent restrictions, or restrictions inconsistent with the * self-inconsistent restrictions, or restrictions inconsistent with the
* relation's CHECK constraints. * relation's CHECK constraints.
* *
* Note: this examines only rel->relid and rel->baserestrictinfo; therefore * Note: this examines only rel->relid, rel->reloptkind, and
* it can be called before filling in other fields of the RelOptInfo. * rel->baserestrictinfo; therefore it can be called before filling in
* other fields of the RelOptInfo.
*/ */
bool bool
relation_excluded_by_constraints(PlannerInfo *root, relation_excluded_by_constraints(PlannerInfo *root,
@ -573,8 +575,10 @@ relation_excluded_by_constraints(PlannerInfo *root,
List *safe_constraints; List *safe_constraints;
ListCell *lc; ListCell *lc;
/* Skip the test if constraint exclusion is disabled */ /* Skip the test if constraint exclusion is disabled for the rel */
if (!constraint_exclusion) if (constraint_exclusion == CONSTRAINT_EXCLUSION_OFF ||
(constraint_exclusion == CONSTRAINT_EXCLUSION_PARTITION &&
rel->reloptkind != RELOPT_OTHER_MEMBER_REL))
return false; return false;
/* /*

View File

@ -10,7 +10,7 @@
* Written by Peter Eisentraut <peter_e@gmx.net>. * Written by Peter Eisentraut <peter_e@gmx.net>.
* *
* IDENTIFICATION * IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/utils/misc/guc.c,v 1.490 2009/01/06 16:39:52 tgl Exp $ * $PostgreSQL: pgsql/src/backend/utils/misc/guc.c,v 1.491 2009/01/07 22:40:49 tgl Exp $
* *
*-------------------------------------------------------------------- *--------------------------------------------------------------------
*/ */
@ -311,6 +311,23 @@ static const struct config_enum_entry backslash_quote_options[] = {
{NULL, 0, false} {NULL, 0, false}
}; };
/*
* Although only "on", "off", and "partition" are documented, we
* accept all the likely variants of "on" and "off".
*/
static const struct config_enum_entry constraint_exclusion_options[] = {
{"partition", CONSTRAINT_EXCLUSION_PARTITION, false},
{"on", CONSTRAINT_EXCLUSION_ON, false},
{"off", CONSTRAINT_EXCLUSION_OFF, false},
{"true", CONSTRAINT_EXCLUSION_ON, true},
{"false", CONSTRAINT_EXCLUSION_OFF, true},
{"yes", CONSTRAINT_EXCLUSION_ON, true},
{"no", CONSTRAINT_EXCLUSION_OFF, true},
{"1", CONSTRAINT_EXCLUSION_ON, true},
{"0", CONSTRAINT_EXCLUSION_OFF, true},
{NULL, 0, false}
};
/* /*
* Options for enum values stored in other modules * Options for enum values stored in other modules
*/ */
@ -635,15 +652,6 @@ static struct config_bool ConfigureNamesBool[] =
&enable_hashjoin, &enable_hashjoin,
true, NULL, NULL true, NULL, NULL
}, },
{
{"constraint_exclusion", PGC_USERSET, QUERY_TUNING_OTHER,
gettext_noop("Enables the planner to use constraints to optimize queries."),
gettext_noop("Child table scans will be skipped if their "
"constraints guarantee that no rows match the query.")
},
&constraint_exclusion,
false, NULL, NULL
},
{ {
{"geqo", PGC_USERSET, QUERY_TUNING_GEQO, {"geqo", PGC_USERSET, QUERY_TUNING_GEQO,
gettext_noop("Enables genetic query optimization."), gettext_noop("Enables genetic query optimization."),
@ -2521,6 +2529,17 @@ static struct config_enum ConfigureNamesEnum[] =
NOTICE, client_message_level_options, NULL, NULL NOTICE, client_message_level_options, NULL, NULL
}, },
{
{"constraint_exclusion", PGC_USERSET, QUERY_TUNING_OTHER,
gettext_noop("Enables the planner to use constraints to optimize queries."),
gettext_noop("Table scans will be skipped if their constraints"
" guarantee that no rows match the query.")
},
&constraint_exclusion,
CONSTRAINT_EXCLUSION_PARTITION, constraint_exclusion_options,
NULL, NULL
},
{ {
{"default_transaction_isolation", PGC_USERSET, CLIENT_CONN_STATEMENT, {"default_transaction_isolation", PGC_USERSET, CLIENT_CONN_STATEMENT,
gettext_noop("Sets the transaction isolation level of each new transaction."), gettext_noop("Sets the transaction isolation level of each new transaction."),

View File

@ -211,7 +211,7 @@
# - Other Planner Options - # - Other Planner Options -
#default_statistics_target = 100 # range 1-10000 #default_statistics_target = 100 # range 1-10000
#constraint_exclusion = off #constraint_exclusion = partition # on, off, or partition
#cursor_tuple_fraction = 0.1 # range 0.0-1.0 #cursor_tuple_fraction = 0.1 # range 0.0-1.0
#from_collapse_limit = 8 #from_collapse_limit = 8
#join_collapse_limit = 8 # 1 disables collapsing of explicit #join_collapse_limit = 8 # 1 disables collapsing of explicit

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group * Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California * Portions Copyright (c) 1994, Regents of the University of California
* *
* $PostgreSQL: pgsql/src/include/optimizer/cost.h,v 1.95 2009/01/01 17:24:00 momjian Exp $ * $PostgreSQL: pgsql/src/include/optimizer/cost.h,v 1.96 2009/01/07 22:40:49 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
@ -29,6 +29,13 @@
#define DEFAULT_EFFECTIVE_CACHE_SIZE 16384 /* measured in pages */ #define DEFAULT_EFFECTIVE_CACHE_SIZE 16384 /* measured in pages */
typedef enum
{
CONSTRAINT_EXCLUSION_OFF, /* do not use c_e */
CONSTRAINT_EXCLUSION_ON, /* apply c_e to all rels */
CONSTRAINT_EXCLUSION_PARTITION /* apply c_e to otherrels only */
} ConstraintExclusionType;
/* /*
* prototypes for costsize.c * prototypes for costsize.c
@ -52,7 +59,7 @@ extern bool enable_hashagg;
extern bool enable_nestloop; extern bool enable_nestloop;
extern bool enable_mergejoin; extern bool enable_mergejoin;
extern bool enable_hashjoin; extern bool enable_hashjoin;
extern bool constraint_exclusion; extern int constraint_exclusion;
extern double clamp_row_est(double nrows); extern double clamp_row_est(double nrows);
extern double index_pages_fetched(double tuples_fetched, BlockNumber pages, extern double index_pages_fetched(double tuples_fetched, BlockNumber pages,