Commit 8f18a880 authored by Robert Haas's avatar Robert Haas

Improve documentation for table partitioning.

Emphasize the new declarative partitioning more, and compare and
contrast it more clearly with inheritance-based partitioning.

Amit Langote, reviewed and somewhat revised by me

Discussion: http://postgr.es/m/a6f99cdb-21e7-1d65-1381-91f2cfa156e2@lab.ntt.co.jp
parent f0523075
...@@ -2772,586 +2772,691 @@ VALUES ('Albany', NULL, NULL, 'NY'); ...@@ -2772,586 +2772,691 @@ VALUES ('Albany', NULL, NULL, 'NY');
</sect2> </sect2>
</sect1> </sect1>
<sect1 id="ddl-partitioned-tables"> <sect1 id="ddl-partitioning">
<title>Partitioned Tables</title> <title>Table Partitioning</title>
<indexterm> <indexterm>
<primary>partitioned table</primary> <primary>partitioning</primary>
</indexterm> </indexterm>
<para> <indexterm>
PostgreSQL offers a way to specify how to divide a table into pieces <primary>table</primary>
called partitions. The table that is divided is referred to as a <secondary>partitioning</secondary>
<firstterm>partitioned table</firstterm>. The specification consists </indexterm>
of the <firstterm>partitioning method</firstterm> and a list of columns
or expressions to be used as the <firstterm>partition key</firstterm>.
</para>
<para>
All rows inserted into a partitioned table will be routed to one of the
<firstterm>partitions</firstterm> based on the value of the partition
key. Each partition has a subset defined by its <firstterm>partition
bounds</firstterm>. Currently supported partitioning methods include
range and list, wherein each partition is assigned a range of keys or
a list of keys, respectively.
</para>
<para> <indexterm>
Partitions may have their own indexes, constraints and default values, <primary>partitioned table</primary>
distinct from other partitions. Partitions do not inherit indexes from </indexterm>
the partitioned table.
</para>
<para> <para>
Partitions may themselves be defined as partitioned tables, referred to as <productname>PostgreSQL</productname> supports basic table
<firstterm>sub-partitioning</firstterm>. See <xref linkend="sql-createtable"> partitioning. This section describes why and how to implement
for more details creating partitioned tables and partitions. It is not partitioning as part of your database design.
currently possible to alter a regular table into a partitioned table or
vice versa. However, it is possible to add a regular table containing
data into a partition of a partitioned table, or remove a partition; see
<xref linkend="sql-altertable"> to learn more about the
<command>ATTACH PARTITION</> and <command>DETACH PARTITION</> sub-commands.
</para> </para>
<para> <sect2 id="ddl-partitioning-overview">
Individual partitions are linked to the partitioned table with inheritance <title>Overview</title>
behind-the-scenes, however it is not possible to use some of the inheritance
features discussed in the previous section with partitioned tables and
partitions. For example, partitions cannot have any other parents than
the partitioned table it is a partition of, nor can a regular table inherit
from a partitioned table making the latter its parent. That means
partitioned table and partitions do not participate in inheritance with
regular tables. Since a partition hierarchy consisting of the
partitioned table and its partitions is still an inheritance hierarchy,
all the normal rules of inheritance apply as described in the previous
section (<xref linkend="ddl-inherit">) with some exceptions, most notably:
<para>
Partitioning refers to splitting what is logically one large table into
smaller physical pieces. Partitioning can provide several benefits:
<itemizedlist> <itemizedlist>
<listitem> <listitem>
<para> <para>
Both <literal>CHECK</literal> and <literal>NOT NULL</literal> Query performance can be improved dramatically in certain situations,
constraints of a partitioned table are always inherited by all its particularly when most of the heavily accessed rows of the table are in a
partitions. There cannot be any <literal>CHECK</literal> constraints single partition or a small number of partitions. The partitioning
that are marked <literal>NO INHERIT</literal>. substitutes for leading columns of indexes, reducing index size and
making it more likely that the heavily-used parts of the indexes
fit in memory.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
The <literal>ONLY</literal> notation used to exclude child tables When queries or updates access a large percentage of a single
would either cause error or will be ignored in some cases for partition, performance can be improved by taking advantage
partitioned tables. For example, specifying <literal>ONLY</literal> of sequential scan of that partition instead of using an
when querying data from a partitioned table would not make much sense, index and random access reads scattered across the whole table.
because all the data is contained in partitions, so this raises an
error. Specifying <literal>ONLY</literal> when modifying schema is
not desirable in certain cases with partitioned tables where it may be
fine for regular inheritance parents (for example, dropping a column
from only the parent); an error will be thrown in that case.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
Partitions cannot have columns that are not present in the parent. Bulk loads and deletes can be accomplished by adding or removing
It is neither possible to specify columns when creating partitions partitions, if that requirement is planned into the partitioning design.
with <command>CREATE TABLE</> nor is it possible to add columns to Doing <command>ALTER TABLE DETACH PARTITION</> or dropping an individual
partitions using <command>ALTER TABLE</>. Tables may be added with partition using <command>DROP TABLE</> is far faster than a bulk
<command>ALTER TABLE ... ATTACH PARTITION</> if their columns exactly operation. These commands also entirely avoid the
match the parent, including oids. <command>VACUUM</command> overhead caused by a bulk <command>DELETE</>.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
One cannot drop a <literal>NOT NULL</literal> constraint on a Seldom-used data can be migrated to cheaper and slower storage media.
partition's column, if the constraint is present in the parent table.
</para> </para>
</listitem> </listitem>
</itemizedlist> </itemizedlist>
The benefits will normally be worthwhile only when a table would
otherwise be very large. The exact point at which a table will
benefit from partitioning depends on the application, although a
rule of thumb is that the size of the table should exceed the physical
memory of the database server.
</para>
<para>
<productname>PostgreSQL</productname> offers built-in support for the
following forms of partitioning:
<variablelist>
<varlistentry>
<term>Range Partitioning</term>
<listitem>
<para>
The table is partitioned into <quote>ranges</quote> defined
by a key column or set of columns, with no overlap between
the ranges of values assigned to different partitions. For
example, one might partition by date ranges, or by ranges of
identifiers for particular business objects.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>List Partitioning</term>
<listitem>
<para>
The table is partitioned by explicitly listing which key values
appear in each partition.
</para>
</listitem>
</varlistentry>
</variablelist>
If your application needs to use other forms of partitioning not listed
above, alternative methods such as inheritance and
<literal>UNION ALL</literal> views can be used instead. Such methods
offer flexibility but do not have some of the performance benefits
of built-in declarative partitioning.
</para>
</sect2>
<sect2 id="ddl-partitioning-declarative">
<title>Declarative Partitioning</title>
<para>
<productname>PostgreSQL</productname> offers a way to specify how to
divide a table into pieces called partitions. The table that is divided
is referred to as a <firstterm>partitioned table</firstterm>. The
specification consists of the <firstterm>partitioning method</firstterm>
and a list of columns or expressions to be used as the
<firstterm>partition key</firstterm>.
</para>
<para>
All rows inserted into a partitioned table will be routed to one of the
<firstterm>partitions</firstterm> based on the value of the partition
key. Each partition has a subset of the data defined by its
<firstterm>partition bounds</firstterm>. Currently supported
partitioning methods include range and list, where each partition is
assigned a range of keys and a list of keys, respectively.
</para>
<para>
Partitions may themselves be defined as partitioned tables, using what is
called <firstterm>sub-partitioning</firstterm>. Partitions may have their
own indexes, constraints and default values, distinct from those of other
partitions. Indexes must be created separately for each partition. See
<xref linkend="sql-createtable"> for more details on creating partitioned
tables and partitions.
</para> </para>
<para> <para>
Partitions can also be foreign tables (see <xref linkend="ddl-foreign-data">), It is not possible to turn a regular table into a partitioned table or
although certain limitations exist currently in their usage. For example, vice versa. However, it is possible to add a regular or partitioned table
data inserted into the partitioned table cannot be routed to foreign table containing data as a partition of a partitioned table, or remove a
partitions. partition from a partitioned table turning it into a standalone table;
see <xref linkend="sql-altertable"> to learn more about the
<command>ATTACH PARTITION</> and <command>DETACH PARTITION</>
sub-commands.
</para> </para>
<para> <para>
There are currently the following limitations of using partitioned tables: Individual partitions are linked to the partitioned table with inheritance
behind-the-scenes; however, it is not possible to use some of the
inheritance features discussed in the previous section with partitioned
tables and partitions. For example, a partition cannot have any parents
other than the partitioned table it is a partition of, nor can a regular
table inherit from a partitioned table making the latter its parent.
That means partitioned table and partitions do not participate in
inheritance with regular tables. Since a partition hierarchy consisting
of the partitioned table and its partitions is still an inheritance
hierarchy, all the normal rules of inheritance apply as described in
<xref linkend="ddl-inherit"> with some exceptions, most notably:
<itemizedlist> <itemizedlist>
<listitem> <listitem>
<para> <para>
It is currently not possible to add same set of indexes on all partitions Both <literal>CHECK</literal> and <literal>NOT NULL</literal>
automatically. Indexes must be added to each partition with separate constraints of a partitioned table are always inherited by all its
commands. partitions. <literal>CHECK</literal> constraints that are marked
<literal>NO INHERIT</literal> are not allowed.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
It is currently not possible to define indexes on partitioned tables The <literal>ONLY</literal> notation used to exclude child tables
that include all rows from all partitions in one global index. will cause an error for partitioned tables in the case of
Consequently, it is not possible to create constraints that are realized schema-modifying commands such as most <literal>ALTER TABLE</literal>
using an index such as <literal>UNIQUE</>. commands. For example, dropping a column from only the parent does
not make sense for partitioned tables.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
Since primary keys are not supported on partitioned tables, Partitions cannot have columns that are not present in the parent. It
foreign keys referencing partitioned tables are not supported, nor is neither possible to specify columns when creating partitions with
are foreign key references from a partitioned table to some other table. <command>CREATE TABLE</> nor is it possible to add columns to
partitions after-the-fact using <command>ALTER TABLE</>. Tables may be
added as a partition with <command>ALTER TABLE ... ATTACH PARTITION</>
only if their columns exactly match the parent, including oids.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
Row triggers, if necessary, must be defined on individual partitions, not You cannot drop the <literal>NOT NULL</literal> constraint on a
the partitioned table as it is currently not supported. partition's column if the constraint is present in the parent table.
</para> </para>
</listitem> </listitem>
</itemizedlist> </itemizedlist>
</para> </para>
<para> <para>
A detailed example that shows how to use partitioned tables is discussed in Partitions can also be foreign tables
the next chapter. (see <xref linkend="sql-createforeigntable">),
although these have some limitations that normal tables do not. For
example, data inserted into the partitioned table is not routed to
foreign table partitions.
</para> </para>
</sect1>
<sect1 id="ddl-partitioning"> <sect3 id="ddl-partitioning-declarative-example">
<title>Partitioning</title> <title>Example</title>
<indexterm> <para>
<primary>partitioning</primary> Suppose we are constructing a database for a large ice cream company.
</indexterm> The company measures peak temperatures every day as well as ice cream
sales in each region. Conceptually, we want a table like:
<indexterm> <programlisting>
<primary>table</primary> CREATE TABLE measurement (
<secondary>partitioning</secondary> city_id int not null,
</indexterm> logdate date not null,
peaktemp int,
unitsales int
);
</programlisting>
<para> We know that most queries will access just the last week's, month's or
<productname>PostgreSQL</productname> supports basic table quarter's data, since the main use of this table will be to prepare
partitioning. This section describes why and how to implement online reports for management. To reduce the amount of old data that
partitioning as part of your database design. needs to be stored, we decide to only keep the most recent 3 years
worth of data. At the beginning of each month we will remove the oldest
month's data. In this situation we can use partitioning to help us meet
all of our different requirements for the measurements table.
</para> </para>
<sect2 id="ddl-partitioning-overview">
<title>Overview</title>
<para> <para>
Partitioning refers to splitting what is logically one large table To use declarative partitioning in this case, use the following steps:
into smaller physical pieces.
Partitioning can provide several benefits:
<itemizedlist>
<listitem>
<para>
Query performance can be improved dramatically in certain situations,
particularly when most of the heavily accessed rows of the table are in a
single partition or a small number of partitions. The partitioning
substitutes for leading columns of indexes, reducing index size and
making it more likely that the heavily-used parts of the indexes
fit in memory.
</para>
</listitem>
<listitem> <orderedlist spacing="compact">
<para> <listitem>
When queries or updates access a large percentage of a single <para>
partition, performance can be improved by taking advantage Create <structname>measurement</structname> table as a partitioned
of sequential scan of that partition instead of using an table by specifying the <literal>PARTITION BY</literal> clause, which
index and random access reads scattered across the whole table. includes the partitioning method (<literal>RANGE</literal> in this
</para> case) and the list of column(s) to use as the partition key.
</listitem>
<listitem> <programlisting>
<para> CREATE TABLE measurement (
Bulk loads and deletes can be accomplished by adding or removing city_id int not null,
partitions, if that requirement is planned into the partitioning design. logdate date not null,
<command>ALTER TABLE NO INHERIT</> or <command>ALTER TABLE DETACH PARTITION</> peaktemp int,
and <command>DROP TABLE</> are both far faster than a bulk operation. unitsales int
These commands also entirely avoid the <command>VACUUM</command> ) PARTITION BY RANGE (logdate);
overhead caused by a bulk <command>DELETE</>. </programlisting>
</para> </para>
</listitem>
<listitem> <para>
<para> You may decide to use multiple columns in the partition key for range
Seldom-used data can be migrated to cheaper and slower storage media. partitioning, if desired. Of course, this will often result in a larger
</para> number of partitions, each of which is individually smaller.
</listitem> criteria. Using fewer columns may lead to coarser-grained
</itemizedlist> A query accessing the partitioned table will have
to scan fewer partitions if the conditions involve some or all of these
columns. For example, consider a table range partitioned using columns
<structfield>lastname</> and <structfield>firstname</> (in that order)
as the partition key.
</para>
</listitem>
The benefits will normally be worthwhile only when a table would <listitem>
otherwise be very large. The exact point at which a table will <para>
benefit from partitioning depends on the application, although a Create partitions. Each partition's definition must specify the bounds
rule of thumb is that the size of the table should exceed the physical that correspond to the partitioning method and partition key of the
memory of the database server. parent. Note that specifying bounds such that the new partition's
</para> values will overlap with those in one or more existing partitions will
cause an error. Inserting data into the parent table that does not map
to one of the existing partitions will cause an error; appropriate
partition must be added manually.
</para>
<para> <para>
Currently, <productname>PostgreSQL</productname> supports partitioning Partitions thus created are in every way normal
using two methods: <productname>PostgreSQL</>
tables (or, possibly, foreign tables). It is possible to specify a
tablespace and storage parameters for each partition separately.
</para>
<variablelist> <para>
<varlistentry> It is not necessary to create table constraints describing partition
<term>Using Table Inheritance</term> boundary condition for partitions. Instead, partition constraints are
generated implicitly from the partition bound specification whenever
there is need to refer to them.
<listitem> <programlisting>
<para> CREATE TABLE measurement_y2006m02 PARTITION OF measurement
Each partition must be created as a child table of a single parent FOR VALUES FROM ('2006-02-01') TO ('2006-03-01')
table. The parent table itself is normally empty; it exists just to
represent the entire data set. You should be familiar with
inheritance (see <xref linkend="ddl-inherit">) before attempting to
set up partitioning with it. This was the only method to implement
partitioning in older versions.
</para>
</listitem>
</varlistentry>
<varlistentry> CREATE TABLE measurement_y2006m03 PARTITION OF measurement
<term>Using Partitioned Tables</term> FOR VALUES FROM ('2006-03-01') TO ('2006-04-01')
<listitem> ...
<para> CREATE TABLE measurement_y2007m11 PARTITION OF measurement
See last section for some general information: FOR VALUES FROM ('2007-11-01') TO ('2007-12-01')
<xref linkend="ddl-partitioned-tables">
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para> CREATE TABLE measurement_y2007m12 PARTITION OF measurement
The following forms of partitioning can be implemented in FOR VALUES FROM ('2007-12-01') TO ('2008-01-01')
<productname>PostgreSQL</productname> using either of the above mentioned TABLESPACE fasttablespace;
methods, although the latter provides dedicated syntax for each:
<variablelist> CREATE TABLE measurement_y2008m01 PARTITION OF measurement
<varlistentry> FOR VALUES FROM ('2008-01-01') TO ('2008-02-01')
<term>Range Partitioning</term> TABLESPACE fasttablespace
WITH (parallel_workers = 4);
</programlisting>
</para>
<listitem> <para>
<para> To implement sub-partitioning, specify the
The table is partitioned into <quote>ranges</quote> defined <literal>PARTITION BY</literal> clause in the commands used to create
by a key column or set of columns, with no overlap between individual partitions, for example:
the ranges of values assigned to different partitions. For
example one might partition by date ranges, or by ranges of
identifiers for particular business objects.
</para>
</listitem>
</varlistentry>
<varlistentry> <programlisting>
<term>List Partitioning</term> CREATE TABLE measurement_y2006m02 PARTITION OF measurement
FOR VALUES FROM ('2006-02-01') TO ('2006-03-01')
PARTITION BY RANGE (peaktemp);
</programlisting>
After creating partitions of <structname>measurement_y2006m02</>,
any data inserted into <structname>measurement</> that is mapped to
<structname>measurement_y2006m02</> (or data that is directly inserted
into <structname>measurement_y2006m02</>, provided it satisfies its
partition constraint) will be further redirected to one of its
partitions based on the <structfield>peaktemp</> column. The partition
key specified may overlap with the parent's partition key, although
care should be taken when specifying the bounds of a sub-partition
such that the set of data it accepts constitutes a subset of what
the partition's own bounds allows; the system does not try to check
whether that's really the case.
</para>
</listitem>
<listitem>
<para>
Create an index on the key column(s), as well as any other indexes you
might want for every partition. (The key index is not strictly
necessary, but in most scenarios it is helpful. If you intend the key
values to be unique then you should always create a unique or
primary-key constraint for each partition.)
<programlisting>
CREATE INDEX ON measurement_y2006m02 (logdate);
CREATE INDEX ON measurement_y2006m03 (logdate);
...
CREATE INDEX ON measurement_y2007m11 (logdate);
CREATE INDEX ON measurement_y2007m12 (logdate);
CREATE INDEX ON measurement_y2008m01 (logdate);
</programlisting>
</para>
</listitem>
<listitem> <listitem>
<para> <para>
The table is partitioned by explicitly listing which key values Ensure that the <xref linkend="guc-constraint-exclusion">
appear in each partition. configuration parameter is not disabled in <filename>postgresql.conf</>.
If it is, queries will not be optimized as desired.
</para> </para>
</listitem> </listitem>
</varlistentry> </orderedlist>
</variablelist>
</para> </para>
</sect2>
<sect2 id="ddl-partitioning-implementation"> <para>
<title>Implementing Partitioning</title> In the above example we would be creating a new partition each month, so
it might be wise to write a script that generates the required DDL
automatically.
</para>
</sect3>
<sect3 id="ddl-partitioning-declarative-maintenance">
<title>Partition Maintenance</title>
<para> <para>
To set up a partitioned table using inheritance, do the following: Normally the set of partitions established when initially defining the
<orderedlist spacing="compact"> the table are not intended to remain static. It is common to want to
<listitem> remove old partitions of data and periodically add new partitions for
<para> new data. One of the most important advantages of partitioning is
Create the <quote>master</quote> table, from which all of the precisely that it allows this otherwise painful task to be executed
partitions will inherit. nearly instantaneously by manipulating the partition structure, rather
</para> than physically moving large amounts of data around.
<para> </para>
This table will contain no data. Do not define any check
constraints on this table, unless you intend them to
be applied equally to all partitions. There is no point
in defining any indexes or unique constraints on it, either.
</para>
</listitem>
<listitem> <para>
<para> The simplest option for removing old data is simply to drop the partition
Create several <quote>child</quote> tables that each inherit from that is no longer necessary:
the master table. Normally, these tables will not add any columns <programlisting>
to the set inherited from the master. DROP TABLE measurement_y2006m02;
</para> </programlisting>
This can very quickly delete millions of records because it doesn't have
to individually delete every record. Note however that the above command
requires taking an <literal>ACCESS EXCLUSIVE</literal> lock on the parent
table.
</para>
<para> <para>
We will refer to the child tables as partitions, though they Another option that is often preferable is to remove the partition from
are in every way normal <productname>PostgreSQL</> tables the partitioned table but retain access to it as a table in its own
(or, possibly, foreign tables). right:
</para>
</listitem>
<listitem> <programlisting>
<para> ALTER TABLE measurement DETACH PARTITION measurement_y2006m02;
Add table constraints to the partition tables to define the </programlisting>
allowed key values in each partition.
</para> This allows further operations to be performed on the data before
it is dropped. For example, this is often a useful time to back up
the data using <command>COPY</>, <application>pg_dump</>, or
similar tools. It might also be a useful time to aggregate data
into smaller formats, perform other data manipulations, or run
reports.
</para>
<para>
Similarly we can add a new partition to handle new data. We can create an
empty partition in the partitioned table just as the original partitions
were created above:
<para>
Typical examples would be:
<programlisting> <programlisting>
CHECK ( x = 1 ) CREATE TABLE measurement_y2008m02 PARTITION OF measurement
CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' )) FOR VALUES FROM ('2008-02-01') TO ('2008-03-01')
CHECK ( outletID &gt;= 100 AND outletID &lt; 200 ) TABLESPACE fasttablespace;
</programlisting> </programlisting>
Ensure that the constraints guarantee that there is no overlap
between the key values permitted in different partitions. A common As an alternative, it is sometimes more convenient to create the
mistake is to set up range constraints like: new table outside the partition structure, and make it a proper
partition later. This allows the data to be loaded, checked, and
transformed prior to it appearing in the partitioned table:
<programlisting> <programlisting>
CHECK ( outletID BETWEEN 100 AND 200 ) CREATE TABLE measurement_y2008m02
CHECK ( outletID BETWEEN 200 AND 300 ) (LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS)
TABLESPACE fasttablespace;
ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
CHECK ( logdate &gt;= DATE '2008-02-01' AND logdate &lt; DATE '2008-03-01' );
\copy measurement_y2008m02 from 'measurement_y2008m02'
-- possibly some other data preparation work
ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02
FOR VALUES FROM ('2008-02-01') TO ('2008-03-01' );
</programlisting> </programlisting>
This is wrong since it is not clear which partition the key value </para>
200 belongs in.
</para>
<para> <para>
Note that there is no difference in Before running the <command>ATTACH PARTITION</> command, it is
syntax between range and list partitioning; those terms are recommended to create a <literal>CHECK</> constraint on the table to
descriptive only. be attached describing the desired partition constraint. That way,
</para> the system will be able to skip the scan to validate the implicit
</listitem> partition constraint. Without such a constraint, the table will be
scanned to validate the partition constraint while holding an
<literal>ACCESS EXCLUSIVE</literal> lock on the parent table.
One may then drop the constraint after <command>ATTACH PARTITION</>
is finished, because it is no longer necessary.
</para>
</sect3>
<listitem> <sect3 id="ddl-partitioning-declarative-limitations">
<para> <title>Limitations</title>
For each partition, create an index on the key column(s),
as well as any other indexes you might want. (The key index is
not strictly necessary, but in most scenarios it is helpful.
If you intend the key values to be unique then you should
always create a unique or primary-key constraint for each
partition.)
</para>
</listitem>
<listitem> <para>
<para> The following limitations apply to partitioned tables:
Optionally, define a trigger or rule to redirect data inserted into <itemizedlist>
the master table to the appropriate partition. <listitem>
</para> <para>
</listitem> There is no facility available to create the matching indexes on all
partitions automatically. Indexes must be added to each partition with
separate commands. This also means that there is no way to create a
primary key, unique constraint, or exclusion constraint spanning all
partitions; it is only possible to constrain each leaf partition
individually.
</para>
</listitem>
<listitem> <listitem>
<para> <para>
Ensure that the <xref linkend="guc-constraint-exclusion"> Since primary keys are not supported on partitioned tables, foreign
configuration parameter is not disabled in keys referencing partitioned tables are not supported, nor are foreign
<filename>postgresql.conf</>. key references from a partitioned table to some other table.
If it is, queries will not be optimized as desired. </para>
</para> </listitem>
</listitem>
<listitem>
<para>
Using the <literal>ON CONFLICT</literal> clause with partitioned tables
will cause an error, because unique or exclusion constraints can only be
created on individual partitions. There is no support for enforcing
uniqueness (or an exclusion constraint) across an entire partitioning
hierarchy.
</para>
</listitem>
</orderedlist> <listitem>
<para>
An <command>UPDATE</> that causes a row to move from one partition to
another fails, because the new value of the row fails to satisfy the
implicit partition constraint of the original partition.
</para>
</listitem>
<listitem>
<para>
Row triggers, if necessary, must be defined on individual partitions,
not the partitioned table.
</para>
</listitem>
</itemizedlist>
</para> </para>
</sect3>
</sect2>
<sect2 id="ddl-partitioning-implementation-inheritance">
<title>Implementation Using Inheritance</title>
<para> <para>
To use partitioned tables, do the following: While the built-in declarative partitioning is suitable for most
<orderedlist spacing="compact"> common use cases, there are some circumstances where a more flexible
approach may be useful. Partitioning can be implemented using table
inheritance, which allows for several features which are not supported
by declarative partitioning, such as:
<itemizedlist>
<listitem> <listitem>
<para> <para>
Create <quote>master</quote> table as a partitioned table by Partitioning enforces a rule that all partitions must have exactly
specifying the <literal>PARTITION BY</literal> clause, which includes the same set of columns as the parent, but table inheritance allows
the partitioning method (<literal>RANGE</literal> or children to have extra columns not present in the parent.
<literal>LIST</literal>) and the list of column(s) to use as the
partition key. To be able to insert data into the table, one must
create partitions, as described below.
</para> </para>
<note>
<para>
To decide when to use multiple columns in the partition key for range
partitioning, consider whether queries accessing the partitioned
in question will include conditions that involve multiple columns,
especially the columns being considered to be the partition key.
If so, the optimizer can create a plan that will scan fewer partitions
if a query's conditions are such that there is equality constraint on
leading partition key columns, because they limit the number of
partitions of interest. The first partition key column with
inequality constraint also further eliminates some partitions of
those chosen by equality constraints on earlier columns.
</para>
</note>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
Create partitions of the master partitioned table, with the partition Table inheritance allows for multiple inheritance.
bounds specified for each partition matching the partitioning method
and partition key of the master table. Note that specifying partition
bounds such that the new partition's values will overlap with one or
more existing partitions will cause an error. It is only after
creating partitions that one is able to insert data into the master
partitioned table, provided it maps to one of the existing partitions.
If a data row does not map to any of the existing partitions, it will
cause an error.
</para>
<para>
Partitions thus created are also in every way normal
<productname>PostgreSQL</> tables (or, possibly, foreign tables),
whereas partitioned tables differ in a number of ways.
</para>
<para>
It is not necessary to create table constraints for partitions.
Instead, partition constraints are generated implicitly whenever
there is a need to refer to them. Also, since any data inserted into
the master partitioned table is automatically inserted into the
appropriate partition, it is not necessary to create triggers for the
same.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
Just like with inheritance, create an index on the key column(s), Declarative partitioning only supports list and range partitioning,
as well as any other indexes you might want for every partition. whereas table inheritance allows data to be divided in a manner of
Note that it is currently not supported to propagate index definition the user's choosing. (Note, however, that if constraint exclusion is
from the master partitioned table to its partitions; in fact, it is unable to prune partitions effectively, query performance will be very
not possible to define indexes on partitioned tables in the first poor.)
place. This might change in future releases.
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
Currently, partitioned tables also depend on constraint exclusion Some operations require a stronger lock when using declarative
for query optimization, so ensure that the partitioning than when using table inheritance. For example, adding
<xref linkend="guc-constraint-exclusion"> configuration parameter is or removing a partition to or from a partitioned table requires taking
not disabled in <filename>postgresql.conf</>. This might change in an <literal>ACCESS EXCLUSIVE</literal> lock on the parent table,
future releases. whereas a <literal>SHARE UPDATE EXCLUSIVE</literal> lock is enough
in the case of regular inheritance.
</para> </para>
</listitem> </listitem>
</itemizedlist>
</orderedlist>
</para> </para>
<para> <sect3 id="ddl-partitioning-inheritance-example">
For example, suppose we are constructing a database for a large <title>Example</title>
ice cream company. The company measures peak temperatures every
day as well as ice cream sales in each region. Conceptually,
we want a table like:
<programlisting>
CREATE TABLE measurement (
city_id int not null,
logdate date not null,
peaktemp int,
unitsales int
);
</programlisting>
We know that most queries will access just the last week's, month's or
quarter's data, since the main use of this table will be to prepare
online reports for management.
To reduce the amount of old data that needs to be stored, we
decide to only keep the most recent 3 years worth of data. At the
beginning of each month we will remove the oldest month's data.
</para>
<para> <para>
In this situation we can use partitioning to help us meet all of our We use the same <structname>measurement</structname> table we used
different requirements for the measurements table. Following the above. To implement it as a partitioned table using inheritance, use
steps outlined above for both methods, partitioning can be set up as the following steps:
follows:
</para>
<para> <orderedlist spacing="compact">
<orderedlist spacing="compact"> <listitem>
<listitem> <para>
<para> Create the <quote>master</quote> table, from which all of the
The master table is the <structname>measurement</> table, declared partitions will inherit. This table will contain no data. Do not
exactly as above. define any check constraints on this table, unless you intend them
</para> to be applied equally to all partitions. There is no point in
</listitem> defining any indexes or unique constraints on it, either. For our
example, master table is the <structname>measurement</structname>
table as originally defined.
</para>
</listitem>
<listitem> <listitem>
<para> <para>
Next we create one partition for each active month: Create several <quote>child</quote> tables that each inherit from
the master table. Normally, these tables will not add any columns
to the set inherited from the master. Just as with declarative
partitioning, these partitions are in every way normal
<productname>PostgreSQL</> tables (or foreign tables).
</para>
<para>
<programlisting> <programlisting>
CREATE TABLE measurement_y2006m02 ( ) INHERITS (measurement); CREATE TABLE measurement_y2006m02 () INHERITS (measurement);
CREATE TABLE measurement_y2006m03 ( ) INHERITS (measurement); CREATE TABLE measurement_y2006m03 () INHERITS (measurement);
... ...
CREATE TABLE measurement_y2007m11 ( ) INHERITS (measurement); CREATE TABLE measurement_y2007m11 () INHERITS (measurement);
CREATE TABLE measurement_y2007m12 ( ) INHERITS (measurement); CREATE TABLE measurement_y2007m12 () INHERITS (measurement);
CREATE TABLE measurement_y2008m01 ( ) INHERITS (measurement); CREATE TABLE measurement_y2008m01 () INHERITS (measurement);
</programlisting> </programlisting>
</para>
</listitem>
Each of the partitions are complete tables in their own right, <listitem>
but they inherit their definitions from the <para>
<structname>measurement</> table. Add non-overlapping table constraints to the partition tables to
</para> define the allowed key values in each partition.
</para>
<para> <para>
This solves one of our problems: deleting old data. Each Typical examples would be:
month, all we will need to do is perform a <command>DROP <programlisting>
TABLE</command> on the oldest child table and create a new CHECK ( x = 1 )
child table for the new month's data. CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' ))
</para> CHECK ( outletID &gt;= 100 AND outletID &lt; 200 )
</listitem> </programlisting>
Ensure that the constraints guarantee that there is no overlap
between the key values permitted in different partitions. A common
mistake is to set up range constraints like:
<programlisting>
CHECK ( outletID BETWEEN 100 AND 200 )
CHECK ( outletID BETWEEN 200 AND 300 )
</programlisting>
This is wrong since it is not clear which partition the key value
200 belongs in.
</para>
<listitem> <para>
<para> It would be better to instead create partitions as follows:
We must provide non-overlapping table constraints. Rather than
just creating the partition tables as above, the table creation
script should really be:
<programlisting> <programlisting>
CREATE TABLE measurement_y2006m02 ( CREATE TABLE measurement_y2006m02 (
CHECK ( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' ) CHECK ( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' )
) INHERITS (measurement); ) INHERITS (measurement);
CREATE TABLE measurement_y2006m03 ( CREATE TABLE measurement_y2006m03 (
CHECK ( logdate &gt;= DATE '2006-03-01' AND logdate &lt; DATE '2006-04-01' ) CHECK ( logdate &gt;= DATE '2006-03-01' AND logdate &lt; DATE '2006-04-01' )
) INHERITS (measurement); ) INHERITS (measurement);
... ...
CREATE TABLE measurement_y2007m11 ( CREATE TABLE measurement_y2007m11 (
CHECK ( logdate &gt;= DATE '2007-11-01' AND logdate &lt; DATE '2007-12-01' ) CHECK ( logdate &gt;= DATE '2007-11-01' AND logdate &lt; DATE '2007-12-01' )
) INHERITS (measurement); ) INHERITS (measurement);
CREATE TABLE measurement_y2007m12 ( CREATE TABLE measurement_y2007m12 (
CHECK ( logdate &gt;= DATE '2007-12-01' AND logdate &lt; DATE '2008-01-01' ) CHECK ( logdate &gt;= DATE '2007-12-01' AND logdate &lt; DATE '2008-01-01' )
) INHERITS (measurement); ) INHERITS (measurement);
CREATE TABLE measurement_y2008m01 (
CHECK ( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
) INHERITS (measurement);
</programlisting>
</para>
</listitem>
<listitem> CREATE TABLE measurement_y2008m01 (
<para> CHECK ( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
We probably need indexes on the key columns too: ) INHERITS (measurement);
</programlisting>
</para>
</listitem>
<listitem>
<para>
For each partition, create an index on the key column(s),
as well as any other indexes you might want.
<programlisting> <programlisting>
CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate); CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate);
CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate); CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate);
...
CREATE INDEX measurement_y2007m11_logdate ON measurement_y2007m11 (logdate); CREATE INDEX measurement_y2007m11_logdate ON measurement_y2007m11 (logdate);
CREATE INDEX measurement_y2007m12_logdate ON measurement_y2007m12 (logdate); CREATE INDEX measurement_y2007m12_logdate ON measurement_y2007m12 (logdate);
CREATE INDEX measurement_y2008m01_logdate ON measurement_y2008m01 (logdate); CREATE INDEX measurement_y2008m01_logdate ON measurement_y2008m01 (logdate);
</programlisting> </programlisting>
</para>
</listitem>
We choose not to add further indexes at this time. <listitem>
</para> <para>
</listitem> We want our application to be able to say <literal>INSERT INTO
measurement ...</> and have the data be redirected into the
<listitem> appropriate partition table. We can arrange that by attaching
<para> a suitable trigger function to the master table.
We want our application to be able to say <literal>INSERT INTO If data will be added only to the latest partition, we can
measurement ...</> and have the data be redirected into the use a very simple trigger function:
appropriate partition table. We can arrange that by attaching
a suitable trigger function to the master table.
If data will be added only to the latest partition, we can
use a very simple trigger function:
<programlisting> <programlisting>
CREATE OR REPLACE FUNCTION measurement_insert_trigger() CREATE OR REPLACE FUNCTION measurement_insert_trigger()
...@@ -3363,9 +3468,11 @@ END; ...@@ -3363,9 +3468,11 @@ END;
$$ $$
LANGUAGE plpgsql; LANGUAGE plpgsql;
</programlisting> </programlisting>
</para>
After creating the function, we create a trigger which <para>
calls the trigger function: After creating the function, we create a trigger which
calls the trigger function:
<programlisting> <programlisting>
CREATE TRIGGER insert_measurement_trigger CREATE TRIGGER insert_measurement_trigger
...@@ -3373,15 +3480,15 @@ CREATE TRIGGER insert_measurement_trigger ...@@ -3373,15 +3480,15 @@ CREATE TRIGGER insert_measurement_trigger
FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger(); FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger();
</programlisting> </programlisting>
We must redefine the trigger function each month so that it always We must redefine the trigger function each month so that it always
points to the current partition. The trigger definition does points to the current partition. The trigger definition does
not need to be updated, however. not need to be updated, however.
</para> </para>
<para> <para>
We might want to insert data and have the server automatically We might want to insert data and have the server automatically
locate the partition into which the row should be added. We locate the partition into which the row should be added. We
could do this with a more complex trigger function, for example: could do this with a more complex trigger function, for example:
<programlisting> <programlisting>
CREATE OR REPLACE FUNCTION measurement_insert_trigger() CREATE OR REPLACE FUNCTION measurement_insert_trigger()
...@@ -3406,170 +3513,107 @@ $$ ...@@ -3406,170 +3513,107 @@ $$
LANGUAGE plpgsql; LANGUAGE plpgsql;
</programlisting> </programlisting>
The trigger definition is the same as before. The trigger definition is the same as before.
Note that each <literal>IF</literal> test must exactly match the Note that each <literal>IF</literal> test must exactly match the
<literal>CHECK</literal> constraint for its partition. <literal>CHECK</literal> constraint for its partition.
</para> </para>
<para>
While this function is more complex than the single-month case,
it doesn't need to be updated as often, since branches can be
added in advance of being needed.
</para>
<note>
<para> <para>
In practice it might be best to check the newest partition first, While this function is more complex than the single-month case,
if most inserts go into that partition. For simplicity we have it doesn't need to be updated as often, since branches can be
shown the trigger's tests in the same order as in other parts added in advance of being needed.
of this example.
</para> </para>
</note>
</listitem>
</orderedlist>
</para>
<para>
Steps when using a partitioned table are as follows:
</para>
<para>
<orderedlist spacing="compact">
<listitem>
<para>
Create the <structname>measurement</> table as a partitioned table:
<programlisting> <note>
CREATE TABLE measurement ( <para>
city_id int not null, In practice it might be best to check the newest partition first,
logdate date not null, if most inserts go into that partition. For simplicity we have
peaktemp int, shown the trigger's tests in the same order as in other parts
unitsales int of this example.
) PARTITION BY RANGE (logdate); </para>
</programlisting> </note>
</para>
</listitem>
<listitem> <para>
<para> A different approach to redirecting inserts into the appropriate
Then create partitions as follows: partition table is to set up rules, instead of a trigger, on the
master table. For example:
<programlisting> <programlisting>
CREATE TABLE measurement_y2006m02 PARTITION OF measurement CREATE RULE measurement_insert_y2006m02 AS
FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'); ON INSERT TO measurement WHERE
CREATE TABLE measurement_y2006m03 PARTITION OF measurement ( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' )
FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'); DO INSTEAD
INSERT INTO measurement_y2006m02 VALUES (NEW.*);
... ...
CREATE TABLE measurement_y2007m11 PARTITION OF measurement CREATE RULE measurement_insert_y2008m01 AS
FOR VALUES FROM ('2007-11-01') TO ('2007-12-01'); ON INSERT TO measurement WHERE
CREATE TABLE measurement_y2007m12 PARTITION OF measurement ( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
FOR VALUES FROM ('2007-12-01') TO ('2008-01-01'); DO INSTEAD
CREATE TABLE measurement_y2008m01 PARTITION OF measurement INSERT INTO measurement_y2008m01 VALUES (NEW.*);
FOR VALUES FROM ('2008-01-01') TO ('2008-02-01');
</programlisting>
</para>
</listitem>
<listitem>
<para>
Create indexes on the key columns just like in case of inheritance
partitions.
</para>
</listitem>
</orderedlist>
<note>
<para>
To implement sub-partitioning, specify the
<literal>PARTITION BY</literal> clause in the commands used to create
individual partitions, for example:
<programlisting>
CREATE TABLE measurement_y2006m02 PARTITION OF measurement
FOR VALUES FROM ('2006-02-01') TO ('2006-03-01')
PARTITION BY RANGE (peaktemp);
</programlisting> </programlisting>
After creating partitions of <structname>measurement_y2006m02</>, any A rule has significantly more overhead than a trigger, but the
data inserted into <structname>measurement</> that is mapped to overhead is paid once per query rather than once per row, so this
<structname>measurement_y2006m02</> will be further redirected to one method might be advantageous for bulk-insert situations. In most
of its partitions based on the <structfield>peaktemp</> column. cases, however, the trigger method will offer better performance.
Partition key specified may overlap with the parent's partition key, </para>
although care must be taken when specifying the bounds of sub-partitions
such that the accepted set of data constitutes a subset of what a
partition's own bounds allows; the system does not try to check if
that's really the case.
</para>
</note>
</para>
<para>
As we can see, a complex partitioning scheme could require a
substantial amount of DDL, although significantly less when using
partitioned tables. In the above example we would be creating a new
partition each month, so it might be wise to write a script that
generates the required DDL automatically.
</para>
</sect2> <para>
Be aware that <command>COPY</> ignores rules. If you want to
use <command>COPY</> to insert data, you'll need to copy into the
correct partition table rather than into the master. <command>COPY</>
does fire triggers, so you can use it normally if you use the trigger
approach.
</para>
<sect2 id="ddl-partitioning-managing-partitions"> <para>
<title>Managing Partitions</title> Another disadvantage of the rule approach is that there is no simple
way to force an error if the set of rules doesn't cover the insertion
date; the data will silently go into the master table instead.
</para>
</listitem>
<para> <listitem>
Normally the set of partitions established when initially <para>
defining the table are not intended to remain static. It is Ensure that the <xref linkend="guc-constraint-exclusion">
common to want to remove old partitions of data and periodically configuration parameter is not disabled in
add new partitions for new data. One of the most important <filename>postgresql.conf</>.
advantages of partitioning is precisely that it allows this If it is, queries will not be optimized as desired.
otherwise painful task to be executed nearly instantaneously by </para>
manipulating the partition structure, rather than physically moving large </listitem>
amounts of data around. </orderedlist>
</para> </para>
<para> <para>
Both the inheritance-based and partitioned table methods allow this to As we can see, a complex partitioning scheme could require a
be done, although the latter requires taking an <literal>ACCESS EXCLUSIVE</literal> substantial amount of DDL. In the above example we would be creating
lock on the master table for various commands mentioned below. a new partition each month, so it might be wise to write a script that
</para> generates the required DDL automatically.
</para>
</sect3>
<para> <sect3 id="ddl-partitioning-inheritance-maintenance">
The simplest option for removing old data is simply to drop the partition <title>Partition Maintenance</title>
that is no longer necessary, which works using both methods of <para>
partitioning: To remove old data quickly, simply to drop the partition that is no
longer necessary:
<programlisting> <programlisting>
DROP TABLE measurement_y2006m02; DROP TABLE measurement_y2006m02;
</programlisting> </programlisting>
This can very quickly delete millions of records because it doesn't have </para>
to individually delete every record.
</para>
<para>
Another option that is often preferable is to remove the partition from
the partitioned table but retain access to it as a table in its own
right:
<programlisting>
ALTER TABLE measurement_y2006m02 NO INHERIT measurement;
</programlisting>
When using a partitioned table: <para>
To remove the partition from the partitioned table but retain access to
it as a table in its own right:
<programlisting> <programlisting>
ALTER TABLE measurement DETACH PARTITION measurement_y2006m02; ALTER TABLE measurement_y2006m02 NO INHERIT measurement;
</programlisting> </programlisting>
</para>
This allows further operations to be performed on the data before <para>
it is dropped. For example, this is often a useful time to back up To add a new partition to handle new data, create an empty partition
the data using <command>COPY</>, <application>pg_dump</>, or just as the original partitions were created above:
similar tools. It might also be a useful time to aggregate data
into smaller formats, perform other data manipulations, or run
reports.
</para>
<para>
Similarly we can add a new partition to handle new data. We can create an
empty partition in the partitioned table just as the original partitions
were created above:
<programlisting> <programlisting>
CREATE TABLE measurement_y2008m02 ( CREATE TABLE measurement_y2008m02 (
...@@ -3577,17 +3621,9 @@ CREATE TABLE measurement_y2008m02 ( ...@@ -3577,17 +3621,9 @@ CREATE TABLE measurement_y2008m02 (
) INHERITS (measurement); ) INHERITS (measurement);
</programlisting> </programlisting>
When using a partitioned table: Alternatively, one may want to create the new table outside the partition
structure, and make it a partition after the data is loaded, checked,
<programlisting> and transformed.
CREATE TABLE measurement_y2008m02 PARTITION OF measurement
FOR VALUES FROM ('2008-02-01') TO ('2008-03-01');
</programlisting>
As an alternative, it is sometimes more convenient to create the
new table outside the partition structure, and make it a proper
partition later. This allows the data to be loaded, checked, and
transformed prior to it appearing in the partitioned table:
<programlisting> <programlisting>
CREATE TABLE measurement_y2008m02 CREATE TABLE measurement_y2008m02
...@@ -3598,31 +3634,74 @@ ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02 ...@@ -3598,31 +3634,74 @@ ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
-- possibly some other data preparation work -- possibly some other data preparation work
ALTER TABLE measurement_y2008m02 INHERIT measurement; ALTER TABLE measurement_y2008m02 INHERIT measurement;
</programlisting> </programlisting>
</para>
</sect3>
<sect3 id="ddl-partitioning-inheritance-caveats">
<title>Caveats</title>
<para>
The following caveats apply to partitioned tables implemented using
inheritance:
<itemizedlist>
<listitem>
<para>
There is no automatic way to verify that all of the
<literal>CHECK</literal> constraints are mutually
exclusive. It is safer to create code that generates
partitions and creates and/or modifies associated objects than
to write each by hand.
</para>
</listitem>
The last of the above commands when using a partitioned table would be: <listitem>
<para>
The schemes shown here assume that the partition key column(s)
of a row never change, or at least do not change enough to require
it to move to another partition. An <command>UPDATE</> that attempts
to do that will fail because of the <literal>CHECK</> constraints.
If you need to handle such cases, you can put suitable update triggers
on the partition tables, but it makes management of the structure
much more complicated.
</para>
</listitem>
<listitem>
<para>
If you are using manual <command>VACUUM</command> or
<command>ANALYZE</command> commands, don't forget that
you need to run them on each partition individually. A command like:
<programlisting> <programlisting>
ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02 ANALYZE measurement;
FOR VALUES FROM ('2008-02-01') TO ('2008-03-01' );
</programlisting> </programlisting>
</para> will only process the master table.
</para>
</listitem>
<tip> <listitem>
<para> <para>
Before running the <command>ATTACH PARTITION</> command, it is <command>INSERT</command> statements with <literal>ON CONFLICT</>
recommended to create a <literal>CHECK</> constraint on the table to clauses are unlikely to work as expected, as the <literal>ON CONFLICT</>
be attached describing the desired partition constraint. Using the action is only taken in case of unique violations on the specified
same, system is able to skip the scan to validate the implicit target relation, not its child relations.
partition constraint. Without such a constraint, the table will be </para>
scanned to validate the partition constraint, while holding an </listitem>
<literal>ACCESS EXCLUSIVE</literal> lock on the parent table.
One may want to drop the constraint after <command>ATTACH PARTITION</> <listitem>
is finished, because it is no longer necessary. <para>
</para> Triggers or rules will be needed to route rows to the desired
</tip> partition, unless the application is explicitly aware of the
</sect2> partitioning scheme. Triggers may be complicated to write, and will
be much slower than the tuple routing performed interally by
declarative partitioning.
</para>
</listitem>
</itemizedlist>
</para>
</sect3>
</sect2>
<sect2 id="ddl-partitioning-constraint-exclusion"> <sect2 id="ddl-partitioning-constraint-exclusion">
<title>Partitioning and Constraint Exclusion</title> <title>Partitioning and Constraint Exclusion</title>
<indexterm> <indexterm>
...@@ -3632,7 +3711,8 @@ ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02 ...@@ -3632,7 +3711,8 @@ ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02
<para> <para>
<firstterm>Constraint exclusion</> is a query optimization technique <firstterm>Constraint exclusion</> is a query optimization technique
that improves performance for partitioned tables defined in the that improves performance for partitioned tables defined in the
fashion described above. As an example: fashion described above (both declaratively partitioned tables and those
implemented using inheritance). As an example:
<programlisting> <programlisting>
SET constraint_exclusion = on; SET constraint_exclusion = on;
...@@ -3715,156 +3795,9 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01'; ...@@ -3715,156 +3795,9 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
are unlikely to benefit. are unlikely to benefit.
</para> </para>
<note>
<para>
Currently, constraint exclusion is also used for partitioned tables.
However, we did not create any <literal>CHECK</literal> constraints
for individual partitions as seen above. In this case, the optimizer
uses internally generated constraint for every partition.
</para>
</note>
</sect2>
<sect2 id="ddl-partitioning-alternatives">
<title>Alternative Partitioning Methods</title>
<para>
A different approach to redirecting inserts into the appropriate
partition table is to set up rules, instead of a trigger, on the
master table (unless it is a partitioned table). For example:
<programlisting>
CREATE RULE measurement_insert_y2006m02 AS
ON INSERT TO measurement WHERE
( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' )
DO INSTEAD
INSERT INTO measurement_y2006m02 VALUES (NEW.*);
...
CREATE RULE measurement_insert_y2008m01 AS
ON INSERT TO measurement WHERE
( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
DO INSTEAD
INSERT INTO measurement_y2008m01 VALUES (NEW.*);
</programlisting>
A rule has significantly more overhead than a trigger, but the overhead
is paid once per query rather than once per row, so this method might be
advantageous for bulk-insert situations. In most cases, however, the
trigger method will offer better performance.
</para>
<para>
Be aware that <command>COPY</> ignores rules. If you want to
use <command>COPY</> to insert data, you'll need to copy into the correct
partition table rather than into the master. <command>COPY</> does fire
triggers, so you can use it normally if you use the trigger approach.
</para>
<para>
Another disadvantage of the rule approach is that there is no simple
way to force an error if the set of rules doesn't cover the insertion
date; the data will silently go into the master table instead.
</para>
<para>
Partitioning can also be arranged using a <literal>UNION ALL</literal>
view, instead of table inheritance. For example,
<programlisting>
CREATE VIEW measurement AS
SELECT * FROM measurement_y2006m02
UNION ALL SELECT * FROM measurement_y2006m03
...
UNION ALL SELECT * FROM measurement_y2007m11
UNION ALL SELECT * FROM measurement_y2007m12
UNION ALL SELECT * FROM measurement_y2008m01;
</programlisting>
However, the need to recreate the view adds an extra step to adding and
dropping individual partitions of the data set. In practice this
method has little to recommend it compared to using inheritance.
</para>
</sect2>
<sect2 id="ddl-partitioning-caveats">
<title>Caveats</title>
<para>
The following caveats apply to using inheritance to implement partitioning:
<itemizedlist>
<listitem>
<para>
There is no automatic way to verify that all of the
<literal>CHECK</literal> constraints are mutually
exclusive. It is safer to create code that generates
partitions and creates and/or modifies associated objects than
to write each by hand.
</para>
</listitem>
<listitem>
<para>
The schemes shown here assume that the partition key column(s)
of a row never change, or at least do not change enough to require
it to move to another partition. An <command>UPDATE</> that attempts
to do that will fail because of the <literal>CHECK</> constraints.
If you need to handle such cases, you can put suitable update triggers
on the partition tables, but it makes management of the structure
much more complicated.
</para>
</listitem>
<listitem>
<para>
If you are using manual <command>VACUUM</command> or
<command>ANALYZE</command> commands, don't forget that
you need to run them on each partition individually. A command like:
<programlisting>
ANALYZE measurement;
</programlisting>
will only process the master table.
</para>
</listitem>
<listitem>
<para>
<command>INSERT</command> statements with <literal>ON CONFLICT</>
clauses are unlikely to work as expected, as the <literal>ON CONFLICT</>
action is only taken in case of unique violations on the specified
target relation, not its child relations.
</para>
</listitem>
</itemizedlist>
</para>
<para>
The following caveats apply to partitioned tables created with the
explicit syntax:
<itemizedlist>
<listitem>
<para>
An <command>UPDATE</> that causes a row to move from one partition to
another fails, because the new value of the row fails to satisfy the
implicit partition constraint of the original partition. This might
change in future releases.
</para>
</listitem>
<listitem>
<para>
<command>INSERT</command> statements with <literal>ON CONFLICT</>
clause are currently not allowed on partitioned tables.
</para>
</listitem>
</itemizedlist>
</para>
<para> <para>
The following caveats apply to constraint exclusion, which is currently The following caveats apply to constraint exclusion, which is used by
used by both inheritance and partitioned tables: both inheritance and partitioned tables:
<itemizedlist> <itemizedlist>
<listitem> <listitem>
...@@ -3888,7 +3821,9 @@ ANALYZE measurement; ...@@ -3888,7 +3821,9 @@ ANALYZE measurement;
contain only comparisons of the partitioning column(s) to constants contain only comparisons of the partitioning column(s) to constants
using B-tree-indexable operators, which applies even to partitioned using B-tree-indexable operators, which applies even to partitioned
tables, because only B-tree-indexable column(s) are allowed in the tables, because only B-tree-indexable column(s) are allowed in the
partition key. partition key. (This is not a problem when using declarative
partitioning, since the automatically generated constraints are simple
enough to be understood by the planner.)
</para> </para>
</listitem> </listitem>
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment