diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 09b5b3ff70..5109778196 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -2772,157 +2772,8 @@ VALUES ('Albany', NULL, NULL, 'NY'); - - Partitioned Tables - - - partitioned table - - - - PostgreSQL offers a way to specify how to divide a table into pieces - called partitions. The table that is divided is referred to as a - partitioned table. The specification consists - of the partitioning method and a list of columns - or expressions to be used as the partition key. - - - - All rows inserted into a partitioned table will be routed to one of the - partitions based on the value of the partition - key. Each partition has a subset defined by its partition - bounds. Currently supported partitioning methods include - range and list, wherein each partition is assigned a range of keys or - a list of keys, respectively. - - - - Partitions may have their own indexes, constraints and default values, - distinct from other partitions. Partitions do not inherit indexes from - the partitioned table. - - - - Partitions may themselves be defined as partitioned tables, referred to as - sub-partitioning. See - for more details creating partitioned tables and partitions. It is not - 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 - to learn more about the - ATTACH PARTITION and DETACH PARTITION sub-commands. - - - - 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, 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 () with some exceptions, most notably: - - - - - Both CHECK and NOT NULL - constraints of a partitioned table are always inherited by all its - partitions. There cannot be any CHECK constraints - that are marked NO INHERIT. - - - - - - The ONLY notation used to exclude child tables - would either cause error or will be ignored in some cases for - partitioned tables. For example, specifying ONLY - when querying data from a partitioned table would not make much sense, - because all the data is contained in partitions, so this raises an - error. Specifying ONLY 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. - - - - - - Partitions cannot have columns that are not present in the parent. - It is neither possible to specify columns when creating partitions - with CREATE TABLE nor is it possible to add columns to - partitions using ALTER TABLE. Tables may be added with - ALTER TABLE ... ATTACH PARTITION if their columns exactly - match the parent, including oids. - - - - - - One cannot drop a NOT NULL constraint on a - partition's column, if the constraint is present in the parent table. - - - - - - - Partitions can also be foreign tables (see ), - although certain limitations exist currently in their usage. For example, - data inserted into the partitioned table cannot be routed to foreign table - partitions. - - - - There are currently the following limitations of using partitioned tables: - - - - It is currently not possible to add same set of indexes on all partitions - automatically. Indexes must be added to each partition with separate - commands. - - - - - - It is currently not possible to define indexes on partitioned tables - that include all rows from all partitions in one global index. - Consequently, it is not possible to create constraints that are realized - using an index such as UNIQUE. - - - - - - Since primary keys are not supported on partitioned tables, - foreign keys referencing partitioned tables are not supported, nor - are foreign key references from a partitioned table to some other table. - - - - - - Row triggers, if necessary, must be defined on individual partitions, not - the partitioned table as it is currently not supported. - - - - - - - A detailed example that shows how to use partitioned tables is discussed in - the next chapter. - - - - - Partitioning + Table Partitioning partitioning @@ -2933,6 +2784,10 @@ VALUES ('Albany', NULL, NULL, 'NY'); partitioning + + partitioned table + + PostgreSQL supports basic table partitioning. This section describes why and how to implement @@ -2942,304 +2797,202 @@ VALUES ('Albany', NULL, NULL, 'NY'); Overview - - Partitioning refers to splitting what is logically one large table - into smaller physical pieces. - Partitioning can provide several benefits: - - - - 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. - - + + Partitioning refers to splitting what is logically one large table into + smaller physical pieces. Partitioning can provide several benefits: + + + + 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. + + - - - When queries or updates access a large percentage of a single - partition, performance can be improved by taking advantage - of sequential scan of that partition instead of using an - index and random access reads scattered across the whole table. - - + + + When queries or updates access a large percentage of a single + partition, performance can be improved by taking advantage + of sequential scan of that partition instead of using an + index and random access reads scattered across the whole table. + + - - - Bulk loads and deletes can be accomplished by adding or removing - partitions, if that requirement is planned into the partitioning design. - ALTER TABLE NO INHERIT or ALTER TABLE DETACH PARTITION - and DROP TABLE are both far faster than a bulk operation. - These commands also entirely avoid the VACUUM - overhead caused by a bulk DELETE. - - + + + Bulk loads and deletes can be accomplished by adding or removing + partitions, if that requirement is planned into the partitioning design. + Doing ALTER TABLE DETACH PARTITION or dropping an individual + partition using DROP TABLE is far faster than a bulk + operation. These commands also entirely avoid the + VACUUM overhead caused by a bulk DELETE. + + - - - Seldom-used data can be migrated to cheaper and slower storage media. - - - + + + Seldom-used data can be migrated to cheaper and slower storage media. + + + - 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. - + 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. + - - Currently, PostgreSQL supports partitioning - using two methods: + + PostgreSQL offers built-in support for the + following forms of partitioning: - - - Using Table Inheritance + + + Range Partitioning - - - Each partition must be created as a child table of a single parent - table. The parent table itself is normally empty; it exists just to - represent the entire data set. You should be familiar with - inheritance (see ) before attempting to - set up partitioning with it. This was the only method to implement - partitioning in older versions. - - - + + + The table is partitioned into ranges 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. + + + - - Using Partitioned Tables + + List Partitioning - - - See last section for some general information: - - - - - - + + + The table is partitioned by explicitly listing which key values + appear in each partition. + + + + - - The following forms of partitioning can be implemented in - PostgreSQL using either of the above mentioned - methods, although the latter provides dedicated syntax for each: - - - - Range Partitioning - - - - The table is partitioned into ranges 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. - - - - - - List Partitioning - - - - The table is partitioned by explicitly listing which key values - appear in each partition. - - - - - + If your application needs to use other forms of partitioning not listed + above, alternative methods such as inheritance and + UNION ALL views can be used instead. Such methods + offer flexibility but do not have some of the performance benefits + of built-in declarative partitioning. + - - Implementing Partitioning + + Declarative Partitioning - - To set up a partitioned table using inheritance, do the following: - - - - Create the master table, from which all of the - partitions will inherit. - - - 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. - - + + PostgreSQL offers a way to specify how to + divide a table into pieces called partitions. The table that is divided + is referred to as a partitioned table. The + specification consists of the partitioning method + and a list of columns or expressions to be used as the + partition key. + - - - Create several child tables that each inherit from - the master table. Normally, these tables will not add any columns - to the set inherited from the master. - + + All rows inserted into a partitioned table will be routed to one of the + partitions based on the value of the partition + key. Each partition has a subset of the data defined by its + partition bounds. Currently supported + partitioning methods include range and list, where each partition is + assigned a range of keys and a list of keys, respectively. + - - We will refer to the child tables as partitions, though they - are in every way normal PostgreSQL tables - (or, possibly, foreign tables). - - + + Partitions may themselves be defined as partitioned tables, using what is + called sub-partitioning. 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 + for more details on creating partitioned + tables and partitions. + - - - Add table constraints to the partition tables to define the - allowed key values in each partition. - + + It is not possible to turn a regular table into a partitioned table or + vice versa. However, it is possible to add a regular or partitioned table + containing data as a partition of a partitioned table, or remove a + partition from a partitioned table turning it into a standalone table; + see to learn more about the + ATTACH PARTITION and DETACH PARTITION + sub-commands. + - - Typical examples would be: - -CHECK ( x = 1 ) -CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' )) -CHECK ( outletID >= 100 AND outletID < 200 ) - - 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: - -CHECK ( outletID BETWEEN 100 AND 200 ) -CHECK ( outletID BETWEEN 200 AND 300 ) - - This is wrong since it is not clear which partition the key value - 200 belongs in. - + + 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 + with some exceptions, most notably: - - Note that there is no difference in - syntax between range and list partitioning; those terms are - descriptive only. - - + + + + Both CHECK and NOT NULL + constraints of a partitioned table are always inherited by all its + partitions. CHECK constraints that are marked + NO INHERIT are not allowed. + + - - - 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.) - - + + + The ONLY notation used to exclude child tables + will cause an error for partitioned tables in the case of + schema-modifying commands such as most ALTER TABLE + commands. For example, dropping a column from only the parent does + not make sense for partitioned tables. + + - - - Optionally, define a trigger or rule to redirect data inserted into - the master table to the appropriate partition. - - + + + Partitions cannot have columns that are not present in the parent. It + is neither possible to specify columns when creating partitions with + CREATE TABLE nor is it possible to add columns to + partitions after-the-fact using ALTER TABLE. Tables may be + added as a partition with ALTER TABLE ... ATTACH PARTITION + only if their columns exactly match the parent, including oids. + + - - - Ensure that the - configuration parameter is not disabled in - postgresql.conf. - If it is, queries will not be optimized as desired. - - + + + You cannot drop the NOT NULL constraint on a + partition's column if the constraint is present in the parent table. + + + + - - + + Partitions can also be foreign tables + (see ), + 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. + - - To use partitioned tables, do the following: - - - - Create master table as a partitioned table by - specifying the PARTITION BY clause, which includes - the partitioning method (RANGE or - LIST) 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. - + + Example - - - 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. - - - - - - - Create partitions of the master partitioned table, with the partition - 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. - - - - Partitions thus created are also in every way normal - PostgreSQL tables (or, possibly, foreign tables), - whereas partitioned tables differ in a number of ways. - - - - 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. - - - - - - Just like with inheritance, create an index on the key column(s), - as well as any other indexes you might want for every partition. - Note that it is currently not supported to propagate index definition - from the master partitioned table to its partitions; in fact, it is - not possible to define indexes on partitioned tables in the first - place. This might change in future releases. - - - - - - Currently, partitioned tables also depend on constraint exclusion - for query optimization, so ensure that the - configuration parameter is - not disabled in postgresql.conf. This might change in - future releases. - - - - - - - - For example, suppose we are constructing a database for a large - 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: + + Suppose we are constructing a database for a large 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: CREATE TABLE measurement ( @@ -3250,108 +3003,460 @@ CREATE TABLE measurement ( ); - 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. - + 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. In this situation we can use partitioning to help us meet + all of our different requirements for the measurements table. + - - In this situation we can use partitioning to help us meet all of our - different requirements for the measurements table. Following the - steps outlined above for both methods, partitioning can be set up as - follows: - + + To use declarative partitioning in this case, use the following steps: - - - - - The master table is the measurement table, declared - exactly as above. - - - - - - Next we create one partition for each active month: + + + + Create measurement table as a partitioned + table by specifying the PARTITION BY clause, which + includes the partitioning method (RANGE in this + case) and the list of column(s) to use as the partition key. -CREATE TABLE measurement_y2006m02 ( ) INHERITS (measurement); -CREATE TABLE measurement_y2006m03 ( ) INHERITS (measurement); +CREATE TABLE measurement ( + city_id int not null, + logdate date not null, + peaktemp int, + unitsales int +) PARTITION BY RANGE (logdate); + + + + + You may decide to use multiple columns in the partition key for range + partitioning, if desired. Of course, this will often result in a larger + number of partitions, each of which is individually smaller. + criteria. Using fewer columns may lead to coarser-grained + 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 + lastname and firstname (in that order) + as the partition key. + + + + + + Create partitions. Each partition's definition must specify the bounds + that correspond to the partitioning method and partition key of the + parent. Note that specifying bounds such that the new partition's + 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. + + + + Partitions thus created are in every way normal + PostgreSQL + tables (or, possibly, foreign tables). It is possible to specify a + tablespace and storage parameters for each partition separately. + + + + It is not necessary to create table constraints describing partition + boundary condition for partitions. Instead, partition constraints are + generated implicitly from the partition bound specification whenever + there is need to refer to them. + + +CREATE TABLE measurement_y2006m02 PARTITION OF measurement + FOR VALUES FROM ('2006-02-01') TO ('2006-03-01') + +CREATE TABLE measurement_y2006m03 PARTITION OF measurement + FOR VALUES FROM ('2006-03-01') TO ('2006-04-01') + ... -CREATE TABLE measurement_y2007m11 ( ) INHERITS (measurement); -CREATE TABLE measurement_y2007m12 ( ) INHERITS (measurement); -CREATE TABLE measurement_y2008m01 ( ) INHERITS (measurement); +CREATE TABLE measurement_y2007m11 PARTITION OF measurement + FOR VALUES FROM ('2007-11-01') TO ('2007-12-01') + +CREATE TABLE measurement_y2007m12 PARTITION OF measurement + FOR VALUES FROM ('2007-12-01') TO ('2008-01-01') + TABLESPACE fasttablespace; + +CREATE TABLE measurement_y2008m01 PARTITION OF measurement + FOR VALUES FROM ('2008-01-01') TO ('2008-02-01') + TABLESPACE fasttablespace + WITH (parallel_workers = 4); + + + + + To implement sub-partitioning, specify the + PARTITION BY clause in the commands used to create + individual partitions, for example: + + +CREATE TABLE measurement_y2006m02 PARTITION OF measurement + FOR VALUES FROM ('2006-02-01') TO ('2006-03-01') + PARTITION BY RANGE (peaktemp); - Each of the partitions are complete tables in their own right, - but they inherit their definitions from the - measurement table. - + After creating partitions of measurement_y2006m02, + any data inserted into measurement that is mapped to + measurement_y2006m02 (or data that is directly inserted + into measurement_y2006m02, provided it satisfies its + partition constraint) will be further redirected to one of its + partitions based on the 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. + + + + + 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.) + + +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); + + + + + - This solves one of our problems: deleting old data. Each - month, all we will need to do is perform a DROP - TABLE on the oldest child table and create a new - child table for the new month's data. + Ensure that the + configuration parameter is not disabled in postgresql.conf. + If it is, queries will not be optimized as desired. + + + + + + + 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. + + + + + Partition Maintenance + + + Normally the set of partitions established when initially defining the + the table are not intended to remain static. It is common to want to + remove old partitions of data and periodically add new partitions for + new data. One of the most important advantages of partitioning is + precisely that it allows this otherwise painful task to be executed + nearly instantaneously by manipulating the partition structure, rather + than physically moving large amounts of data around. + + + + The simplest option for removing old data is simply to drop the partition + that is no longer necessary: + +DROP TABLE measurement_y2006m02; + + 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 ACCESS EXCLUSIVE lock on the parent + table. + + + + 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: + + +ALTER TABLE measurement DETACH PARTITION measurement_y2006m02; + + + 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 COPY, 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. + + + + 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: + + +CREATE TABLE measurement_y2008m02 PARTITION OF measurement + FOR VALUES FROM ('2008-02-01') TO ('2008-03-01') + TABLESPACE fasttablespace; + + + 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: + + +CREATE TABLE measurement_y2008m02 + (LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS) + TABLESPACE fasttablespace; + +ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02 + CHECK ( logdate >= DATE '2008-02-01' AND logdate < 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' ); + + + + + Before running the ATTACH PARTITION command, it is + recommended to create a CHECK constraint on the table to + be attached describing the desired partition constraint. That way, + the system will be able to skip the scan to validate the implicit + partition constraint. Without such a constraint, the table will be + scanned to validate the partition constraint while holding an + ACCESS EXCLUSIVE lock on the parent table. + One may then drop the constraint after ATTACH PARTITION + is finished, because it is no longer necessary. + + + + + Limitations + + + The following limitations apply to partitioned tables: + + + + 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. + + + + + + Since primary keys are not supported on partitioned tables, foreign + keys referencing partitioned tables are not supported, nor are foreign + key references from a partitioned table to some other table. + + + + + + Using the ON CONFLICT 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. + + + + + + An 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. + + + + + + Row triggers, if necessary, must be defined on individual partitions, + not the partitioned table. + + + + + + + + + Implementation Using Inheritance + + While the built-in declarative partitioning is suitable for most + 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: + + + + + Partitioning enforces a rule that all partitions must have exactly + the same set of columns as the parent, but table inheritance allows + children to have extra columns not present in the parent. - We must provide non-overlapping table constraints. Rather than - just creating the partition tables as above, the table creation - script should really be: + Table inheritance allows for multiple inheritance. + + + + + + Declarative partitioning only supports list and range partitioning, + whereas table inheritance allows data to be divided in a manner of + the user's choosing. (Note, however, that if constraint exclusion is + unable to prune partitions effectively, query performance will be very + poor.) + + + + + + Some operations require a stronger lock when using declarative + partitioning than when using table inheritance. For example, adding + or removing a partition to or from a partitioned table requires taking + an ACCESS EXCLUSIVE lock on the parent table, + whereas a SHARE UPDATE EXCLUSIVE lock is enough + in the case of regular inheritance. + + + + + + + Example + + + We use the same measurement table we used + above. To implement it as a partitioned table using inheritance, use + the following steps: + + + + + Create the master table, from which all of the + partitions will inherit. 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. For our + example, master table is the measurement + table as originally defined. + + + + + + Create several child 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 + PostgreSQL tables (or foreign tables). + + + + +CREATE TABLE measurement_y2006m02 () INHERITS (measurement); +CREATE TABLE measurement_y2006m03 () INHERITS (measurement); +... +CREATE TABLE measurement_y2007m11 () INHERITS (measurement); +CREATE TABLE measurement_y2007m12 () INHERITS (measurement); +CREATE TABLE measurement_y2008m01 () INHERITS (measurement); + + + + + + + Add non-overlapping table constraints to the partition tables to + define the allowed key values in each partition. + + + + Typical examples would be: + +CHECK ( x = 1 ) +CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' )) +CHECK ( outletID >= 100 AND outletID < 200 ) + + 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: + +CHECK ( outletID BETWEEN 100 AND 200 ) +CHECK ( outletID BETWEEN 200 AND 300 ) + + This is wrong since it is not clear which partition the key value + 200 belongs in. + + + + It would be better to instead create partitions as follows: CREATE TABLE measurement_y2006m02 ( CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' ) ) INHERITS (measurement); + CREATE TABLE measurement_y2006m03 ( CHECK ( logdate >= DATE '2006-03-01' AND logdate < DATE '2006-04-01' ) ) INHERITS (measurement); + ... CREATE TABLE measurement_y2007m11 ( CHECK ( logdate >= DATE '2007-11-01' AND logdate < DATE '2007-12-01' ) ) INHERITS (measurement); + CREATE TABLE measurement_y2007m12 ( CHECK ( logdate >= DATE '2007-12-01' AND logdate < DATE '2008-01-01' ) ) INHERITS (measurement); + CREATE TABLE measurement_y2008m01 ( CHECK ( logdate >= DATE '2008-01-01' AND logdate < DATE '2008-02-01' ) ) INHERITS (measurement); - - - - - - We probably need indexes on the key columns too: + + + + + For each partition, create an index on the key column(s), + as well as any other indexes you might want. CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate); CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate); -... CREATE INDEX measurement_y2007m11_logdate ON measurement_y2007m11 (logdate); CREATE INDEX measurement_y2007m12_logdate ON measurement_y2007m12 (logdate); CREATE INDEX measurement_y2008m01_logdate ON measurement_y2008m01 (logdate); + + - We choose not to add further indexes at this time. - - - - - - We want our application to be able to say INSERT INTO - measurement ... and have the data be redirected into the - 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: + + + We want our application to be able to say INSERT INTO + measurement ... and have the data be redirected into the + 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: CREATE OR REPLACE FUNCTION measurement_insert_trigger() @@ -3363,9 +3468,11 @@ END; $$ LANGUAGE plpgsql; + - After creating the function, we create a trigger which - calls the trigger function: + + After creating the function, we create a trigger which + calls the trigger function: CREATE TRIGGER insert_measurement_trigger @@ -3373,15 +3480,15 @@ CREATE TRIGGER insert_measurement_trigger FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger(); - We must redefine the trigger function each month so that it always - points to the current partition. The trigger definition does - not need to be updated, however. - + We must redefine the trigger function each month so that it always + points to the current partition. The trigger definition does + not need to be updated, however. + - - We might want to insert data and have the server automatically - locate the partition into which the row should be added. We - could do this with a more complex trigger function, for example: + + We might want to insert data and have the server automatically + locate the partition into which the row should be added. We + could do this with a more complex trigger function, for example: CREATE OR REPLACE FUNCTION measurement_insert_trigger() @@ -3406,170 +3513,107 @@ $$ LANGUAGE plpgsql; - The trigger definition is the same as before. - Note that each IF test must exactly match the - CHECK constraint for its partition. - - - - 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. - - - - - In practice it might be best to check the newest partition first, - if most inserts go into that partition. For simplicity we have - shown the trigger's tests in the same order as in other parts - of this example. + The trigger definition is the same as before. + Note that each IF test must exactly match the + CHECK constraint for its partition. - - - - - - Steps when using a partitioned table are as follows: - + + 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. + - - - - - Create the measurement table as a partitioned table: + + + In practice it might be best to check the newest partition first, + if most inserts go into that partition. For simplicity we have + shown the trigger's tests in the same order as in other parts + of this example. + + + + + A different approach to redirecting inserts into the appropriate + partition table is to set up rules, instead of a trigger, on the + master table. For example: -CREATE TABLE measurement ( - city_id int not null, - logdate date not null, - peaktemp int, - unitsales int -) PARTITION BY RANGE (logdate); - - - - - - - Then create partitions as follows: - - -CREATE TABLE measurement_y2006m02 PARTITION OF measurement - FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'); -CREATE TABLE measurement_y2006m03 PARTITION OF measurement - FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'); +CREATE RULE measurement_insert_y2006m02 AS +ON INSERT TO measurement WHERE + ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' ) +DO INSTEAD + INSERT INTO measurement_y2006m02 VALUES (NEW.*); ... -CREATE TABLE measurement_y2007m11 PARTITION OF measurement - FOR VALUES FROM ('2007-11-01') TO ('2007-12-01'); -CREATE TABLE measurement_y2007m12 PARTITION OF measurement - FOR VALUES FROM ('2007-12-01') TO ('2008-01-01'); -CREATE TABLE measurement_y2008m01 PARTITION OF measurement - FOR VALUES FROM ('2008-01-01') TO ('2008-02-01'); - - - - - - - Create indexes on the key columns just like in case of inheritance - partitions. - - - - - - - To implement sub-partitioning, specify the - PARTITION BY clause in the commands used to create - individual partitions, for example: - - -CREATE TABLE measurement_y2006m02 PARTITION OF measurement - FOR VALUES FROM ('2006-02-01') TO ('2006-03-01') - PARTITION BY RANGE (peaktemp); +CREATE RULE measurement_insert_y2008m01 AS +ON INSERT TO measurement WHERE + ( logdate >= DATE '2008-01-01' AND logdate < DATE '2008-02-01' ) +DO INSTEAD + INSERT INTO measurement_y2008m01 VALUES (NEW.*); - After creating partitions of measurement_y2006m02, any - data inserted into measurement that is mapped to - measurement_y2006m02 will be further redirected to one - of its partitions based on the peaktemp column. - Partition key specified may overlap with the parent's partition key, - 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. - - - + 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. + - - 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. - + + Be aware that COPY ignores rules. If you want to + use COPY to insert data, you'll need to copy into the + correct partition table rather than into the master. COPY + does fire triggers, so you can use it normally if you use the trigger + approach. + - + + 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. + + - - Managing Partitions + + + Ensure that the + configuration parameter is not disabled in + postgresql.conf. + If it is, queries will not be optimized as desired. + + + + - - Normally the set of partitions established when initially - defining the table are not intended to remain static. It is - common to want to remove old partitions of data and periodically - add new partitions for new data. One of the most important - advantages of partitioning is precisely that it allows this - otherwise painful task to be executed nearly instantaneously by - manipulating the partition structure, rather than physically moving large - amounts of data around. - + + As we can see, a complex partitioning scheme could require a + substantial amount of DDL. 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. + + - - Both the inheritance-based and partitioned table methods allow this to - be done, although the latter requires taking an ACCESS EXCLUSIVE - lock on the master table for various commands mentioned below. - - - - The simplest option for removing old data is simply to drop the partition - that is no longer necessary, which works using both methods of - partitioning: + + Partition Maintenance + + To remove old data quickly, simply to drop the partition that is no + longer necessary: DROP TABLE measurement_y2006m02; - This can very quickly delete millions of records because it doesn't have - to individually delete every record. - + + + + To remove the partition from the partitioned table but retain access to + it as a table in its own right: - - 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: ALTER TABLE measurement_y2006m02 NO INHERIT measurement; + - When using a partitioned table: - - -ALTER TABLE measurement DETACH PARTITION measurement_y2006m02; - - - 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 COPY, 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. - - - - 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: + + To add a new partition to handle new data, create an empty partition + just as the original partitions were created above: CREATE TABLE measurement_y2008m02 ( @@ -3577,17 +3621,9 @@ CREATE TABLE measurement_y2008m02 ( ) INHERITS (measurement); - When using a partitioned table: - - -CREATE TABLE measurement_y2008m02 PARTITION OF measurement - FOR VALUES FROM ('2008-02-01') TO ('2008-03-01'); - - - 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: + Alternatively, one may want to create the new table outside the partition + structure, and make it a partition after the data is loaded, checked, + and transformed. CREATE TABLE measurement_y2008m02 @@ -3597,32 +3633,75 @@ ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02 \copy measurement_y2008m02 from 'measurement_y2008m02' -- possibly some other data preparation work ALTER TABLE measurement_y2008m02 INHERIT measurement; - - - The last of the above commands when using a partitioned table would be: - - -ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02 - FOR VALUES FROM ('2008-02-01') TO ('2008-03-01' ); + - - - Before running the ATTACH PARTITION command, it is - recommended to create a CHECK constraint on the table to - be attached describing the desired partition constraint. Using the - same, system is able to skip the scan to validate the implicit - partition constraint. Without such a constraint, the table will be - scanned to validate the partition constraint, while holding an - ACCESS EXCLUSIVE lock on the parent table. - One may want to drop the constraint after ATTACH PARTITION - is finished, because it is no longer necessary. - - - + + Caveats - + + The following caveats apply to partitioned tables implemented using + inheritance: + + + + There is no automatic way to verify that all of the + CHECK 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. + + + + + + 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 UPDATE that attempts + to do that will fail because of the 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. + + + + + + If you are using manual VACUUM or + ANALYZE commands, don't forget that + you need to run them on each partition individually. A command like: + +ANALYZE measurement; + + will only process the master table. + + + + + + INSERT statements with ON CONFLICT + clauses are unlikely to work as expected, as the ON CONFLICT + action is only taken in case of unique violations on the specified + target relation, not its child relations. + + + + + + Triggers or rules will be needed to route rows to the desired + partition, unless the application is explicitly aware of the + partitioning scheme. Triggers may be complicated to write, and will + be much slower than the tuple routing performed interally by + declarative partitioning. + + + + + + + + Partitioning and Constraint Exclusion @@ -3632,7 +3711,8 @@ ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02 Constraint exclusion is a query optimization technique 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: SET constraint_exclusion = on; @@ -3715,156 +3795,9 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01'; are unlikely to benefit. - - - Currently, constraint exclusion is also used for partitioned tables. - However, we did not create any CHECK constraints - for individual partitions as seen above. In this case, the optimizer - uses internally generated constraint for every partition. - - - - - - - Alternative Partitioning Methods - - - 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: - - -CREATE RULE measurement_insert_y2006m02 AS -ON INSERT TO measurement WHERE - ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' ) -DO INSTEAD - INSERT INTO measurement_y2006m02 VALUES (NEW.*); -... -CREATE RULE measurement_insert_y2008m01 AS -ON INSERT TO measurement WHERE - ( logdate >= DATE '2008-01-01' AND logdate < DATE '2008-02-01' ) -DO INSTEAD - INSERT INTO measurement_y2008m01 VALUES (NEW.*); - - - 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. - - - - Be aware that COPY ignores rules. If you want to - use COPY to insert data, you'll need to copy into the correct - partition table rather than into the master. COPY does fire - triggers, so you can use it normally if you use the trigger approach. - - - - 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. - - - - Partitioning can also be arranged using a UNION ALL - view, instead of table inheritance. For example, - - -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; - - - 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. - - - - - - Caveats - - The following caveats apply to using inheritance to implement partitioning: - - - - There is no automatic way to verify that all of the - CHECK 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. - - - - - - 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 UPDATE that attempts - to do that will fail because of the 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. - - - - - - If you are using manual VACUUM or - ANALYZE commands, don't forget that - you need to run them on each partition individually. A command like: - -ANALYZE measurement; - - will only process the master table. - - - - - - INSERT statements with ON CONFLICT - clauses are unlikely to work as expected, as the ON CONFLICT - action is only taken in case of unique violations on the specified - target relation, not its child relations. - - - - - - - The following caveats apply to partitioned tables created with the - explicit syntax: - - - - An 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. - - - - - - INSERT statements with ON CONFLICT - clause are currently not allowed on partitioned tables. - - - - - - - - The following caveats apply to constraint exclusion, which is currently - used by both inheritance and partitioned tables: + The following caveats apply to constraint exclusion, which is used by + both inheritance and partitioned tables: @@ -3888,7 +3821,9 @@ ANALYZE measurement; contain only comparisons of the partitioning column(s) to constants using B-tree-indexable operators, which applies even to partitioned 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.)