diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index a1c1496cd2b..aabcebd7cd4 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -1,5 +1,5 @@ Server Configuration @@ -1970,13 +1970,13 @@ archive_command = 'copy "%p" /mnt/server/archivedir/"%f"' # Windows Enables or disables the query planner's use of table constraints to - limit table access. The default is off. + optimize queries. The default is off. When this parameter is on, the planner compares query conditions with table CHECK constraints, and - omits scanning tables where the conditions contradict the + omits scanning tables for which the conditions contradict the constraints. (Presently this is done only for child tables of inheritance scans.) For example: @@ -2010,7 +2010,7 @@ SELECT * FROM parent WHERE key = 2400; - Refer to for more information + Refer to for more information on using constraint exclusion and partitioning. diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index a3c95521177..75aabc3f70f 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1,4 +1,4 @@ - + Data Definition @@ -12,7 +12,7 @@ Subsequently, we discuss how tables can be organized into schemas, and how privileges can be assigned to tables. Finally, we will briefly look at other features that affect the data storage, - such as views, functions, and triggers. + such as inheritance, views, functions, and triggers. @@ -399,11 +399,9 @@ CREATE TABLE products ( constraint described in the next section can be used. - - Check constraints can also be used to enhance performance with - very large tables, when used in conjunction with the parameter. This is discussed - in more detail in . + + Check constraints can be useful for enhancing the performance of + partitioned tables. For details see . @@ -895,8 +893,8 @@ CREATE TABLE order_items ( The OID of the table containing this row. This column is particularly handy for queries that select from inheritance - hierarchies, since without it, it's difficult to tell which - individual table a row came from. The + hierarchies (see ), since without it, + it's difficult to tell which individual table a row came from. The tableoid can be joined against the oid column of pg_class to obtain the table name. @@ -1044,842 +1042,6 @@ CREATE TABLE order_items ( - - Inheritance - - - not-null constraint - - - - constraint - NOT NULL - - - - PostgreSQL implements table inheritance - which can be a useful tool for database designers. SQL:1999 and - later define a type inheritance feature, which differs in many - respects from the features described here. - - - - Let's start with an example: suppose we are trying to build a data - model for cities. Each state has many cities, but only one - capital. We want to be able to quickly retrieve the capital city - for any particular state. This can be done by creating two tables, - one for state capitals and one for cities that are not - capitals. However, what happens when we want to ask for data about - a city, regardless of whether it is a capital or not? The - inheritance feature can help to resolve this problem. We define the - capitals table so that it inherits from - cities: - - -CREATE TABLE cities ( - name text, - population float, - altitude int -- in feet -); - -CREATE TABLE capitals ( - state char(2) -) INHERITS (cities); - - - In this case, a row of capitals inherits - all the columns of its parent table, cities. State - capitals have an extra attribute, state, that shows - their state. - - - - In PostgreSQL, a table can inherit from - zero or more other tables, and a query can reference either all - rows of a table or all rows of a table plus all of its descendants. - For example, the following query finds the names of all cities, - including state capitals, that are located at an altitude over - 500ft: - - -SELECT name, altitude - FROM cities - WHERE altitude > 500; - - - which returns: - - - name | altitude ------------+---------- - Las Vegas | 2174 - Mariposa | 1953 - Madison | 845 - - - - - On the other hand, the following query finds all the cities that - are not state capitals and are situated at an altitude over 500ft: - - -SELECT name, altitude - FROM ONLY cities - WHERE altitude > 500; - - name | altitude ------------+---------- - Las Vegas | 2174 - Mariposa | 1953 - - - - - Here the ONLY keyword indicates that the query - should apply only to cities, and not any tables - below cities in the inheritance hierarchy. Many - of the commands that we have already discussed — - SELECT, UPDATE and - DELETE — support the - ONLY keyword. - - - - Inheritance and Permissions - - Because permissions are not inherited automatically, a user - attempting to access a parent table must either have at least the - same permission for the child table or must use the - ONLY notation. If creating a new inheritance - relationship in an existing system be careful that this does not - create problems. - - - - - Inheritance does not automatically propagate data from - INSERT or COPY commands to - other tables in the inheritance hierarchy. In our example, the - following INSERT statement will fail: - -INSERT INTO cities -(name, population, altitude, state) -VALUES ('New York', NULL, NULL, 'NY'); - - We might hope that the data would be somehow routed to the - capitals table, though this does not happen. If - the child has no locally defined columns, then it is possible to - route data from the parent to the child using a rule, see . This is not possible with the above - INSERT statement because the state column - does not exist on both parent and child tables. - - - - In some cases you may wish to know which table a particular row - originated from. There is a system column called - tableoid in each table which can tell you the - originating table: - - -SELECT c.tableoid, c.name, c.altitude -FROM cities c -WHERE c.altitude > 500; - - - which returns: - - - tableoid | name | altitude -----------+-----------+---------- - 139793 | Las Vegas | 2174 - 139793 | Mariposa | 1953 - 139798 | Madison | 845 - - - (If you try to reproduce this example, you will probably get - different numeric OIDs.) By doing a join with - pg_class you can see the actual table names: - - -SELECT p.relname, c.name, c.altitude -FROM cities c, pg_class p -WHERE c.altitude > 500 and c.tableoid = p.oid; - - - which returns: - - - relname | name | altitude -----------+-----------+---------- - cities | Las Vegas | 2174 - cities | Mariposa | 1953 - capitals | Madison | 845 - - - - - As shown above, a child table may locally define columns as well as - inheriting them from their parents. However, a locally defined - column cannot override the data type of an inherited column of the - same name. A table can inherit from a table that has itself - inherited from other tables. A table can also inherit from more - than one parent table, in which case it inherits the union of the - columns defined by the parent tables. Inherited columns with - duplicate names and data types will be merged so that only a single - column is stored. - - - - Table inheritance can currently only be defined using the - statement. The related statement CREATE TABLE ... AS - SELECT does not allow inheritance to be specified. There - is no way to add an inheritance link to make an existing table into - a child table. Similarly, there is no way to remove an inheritance - link from a child table once it has been defined, other than using - DROP TABLE. A parent table cannot be dropped - while any of its children remain. If you wish to remove a table and - all of its descendants, then you can do so using the - CASCADE option of the statement. - - - - Check constraints can be defined on tables within an inheritance - hierarchy. All check constraints on a parent table are - automatically inherited by all of their children. It is currently - possible to inherit mutually exclusive check constraints, but that - definition quickly shows itself since all attempted row inserts - will be rejected. - - - - will - propogate any changes in data definition on columns or check - constraints down the inheritance hierarchy. Again, dropping - columns or constraints on parent tables is only possible when using - the CASCADE option. ALTER - TABLE follows the same rules for duplicate column merging - and rejection that apply during CREATE TABLE. - - - - Both parent and child tables can have primary and foreign keys, so - that they can take part normally on both the referencing and - referenced sides of a foreign key constraint. Indexes may be - defined on any of these columns whether or not they are inherited. - However, a serious current limitation of the inheritance feature is - that indexes (including unique constraints) and foreign key - constraints only apply to single tables and do not also index their - inheritance children. This is true on both sides of a foreign key - constraint. Thus, in the terms of the above example: - - - - - If we declared cities.name to be - UNIQUE or a PRIMARY KEY, this would not stop the - capitals table from having rows with names duplicating - rows in cities. And those duplicate rows would by - default show up in queries from cities. In fact, by - default capitals would have no unique constraint at all, - and so could contain multiple rows with the same name. - You could add a unique constraint to capitals, but this - would not prevent duplication compared to cities. - - - - - - Similarly, if we were to specify that - cities.name REFERENCES some - other table, this constraint would not automatically propagate to - capitals. However, it is possible to set up a - foreign key such as capitals.name - REFERENCES states.name. - So it is possible to workaround this restriction by manually adding - foreign keys to each child table. - - - - - - Specifying that another table's column REFERENCES - cities(name) would allow the other table to contain city names, but - not capital names. There is no good workaround for this case. - - - - - These deficiencies will probably be fixed in some future release, - but in the meantime considerable care is needed in deciding whether - inheritance is useful for your problem. - - - - - Deprecated - - In previous versions of PostgreSQL, the - default behavior was not to include child tables in queries. This was - found to be error prone and is also in violation of the SQL - standard. Under the old syntax, to get the sub-tables you append - * to the table name. For example: - -SELECT * from cities*; - - You can still explicitly specify scanning child tables by - appending *, as well as explicitly specify not - scanning child tables by writing ONLY. But - beginning in version 7.1, the default behavior for an undecorated - table name is to scan its child tables too, whereas before the - default was not to do so. To get the old default behavior, - disable the configuration - option. - - - - - - - Constraint Exclusion and Partitioning - - - partitioning - - - - constraint exclusion - - - - PostgreSQL supports basic table - partitioning. This section describes why and how you can implement - this as part of your database design. - - - - Overview - - - Currently, partitioning is implemented in conjunction with table - inheritance only, though using fully SQL compliant syntax. - Table inheritance allows tables to be split into partitions, and - constraint exclusion allows partitions to be selectively combined - as needed to satisfy a particular SELECT - statement. You should be familiar with inheritance (see ) before attempting to implement - partitioning. - - - - Partitioning can provide several benefits: - - - - Query performance can be improved dramatically for certain kinds - of queries without the need to maintain costly indexes. - - - - - - Insert performance can be improved by breaking down a large - index into multiple pieces. When an index no longer fits easily - in memory, both read and write operations on the index take - progressively more disk accesses. - - - - - - Bulk deletes may be avoided altogether by simply removing one of the - partitions, if that requirement is planned into the partitioning design. - - - - - - 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 the - size of the table should usually exceed the physical memory of the - database server. - - - - The following partitioning types are supported by - PostgreSQL &version;: - - - - Range Partitioning - - - - The table is partitioned along a range defined - by a single column or set of columns, with no overlap between - partitions. Examples might be a date range or a range of - identifiers for particular business objects. - - - - - - List Partitioning - - - - The table is partitioned by explicitly listing which values - relate to each partition. - - - - - - Hash partitioning is not currently supported. - - - - - Implementing Partitioning - - - Partitioning a table is a straightforward process. There - are a wide range of options for you to consider, so judging exactly - when and how to implement partitioning is a more complex topic. We - will address that complexity primarily through the examples in this - section. - - - - To use partitioning, 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 - constraints or keys on this table, unless you intend them to - be applied equally to all partitions. - - - - - - Create several child tables that inherit from - the master table. - - - - We will refer to the child tables as partitions, though they - are in every way normal PostgreSQL tables. - - - - - - Add table constraints to define the allowed values in each partition. - - - Only clauses of the form [COLUMN] [OPERATOR] [CONSTANT(s)] will be used - for constraint exclusion. Simple examples would be: - -CHECK ( x = 1 ) -CHECK ( county IN ( 'Oxfordshire','Buckinghamshire','Warwickshire' )) -CHECK ( outletID BETWEEN 1 AND 99 ) - - - These can be linked together with the Boolean operators - AND and OR to form - complex constraints. Note that there is no difference in - syntax between range and list partitioning; those terms are - descriptive only. Ensure that the set of values in each child - table do not overlap. - - - - - - Add any other indexes you want to the partitions, bearing in - mind that it is always more efficient to add indexes after - data has been bulk loaded. - - - - - - Optionally, define a rule or trigger to redirect modifications - of the master table to the appropriate partition. - - - - - - - - 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. They have two - tables: - - -CREATE TABLE cities ( - id int not null, - name text not null, - altitude int -- in feet -); - -CREATE TABLE measurement ( - city_id int not null, - logdate date not null, - peaktemp int, - unitsales int -); - - - 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 remove the oldest month's data. - - - - Most queries just access the last week, month or quarter's data, - since we need to keep track of sales. As a result we have a large table, - yet only the most frequent 10% is accessed. Most of these queries - are online reports for various levels of management. These queries access - much of the table, so it is difficult to build enough indexes and at - the same time allow us to keep loading all of the data fast enough. - Yet, the reports are online so we need to respond quickly. - - - - 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, partitioning can be enabled as follows: - - - - - - - The measurement table is our master table. - - - - - - Next we create one partition for each month using inheritance: - - -CREATE TABLE measurement_yy04mm02 ( ) INHERITS (measurement); -CREATE TABLE measurement_yy04mm03 ( ) INHERITS (measurement); -... -CREATE TABLE measurement_yy05mm11 ( ) INHERITS (measurement); -CREATE TABLE measurement_yy05mm12 ( ) INHERITS (measurement); -CREATE TABLE measurement_yy06mm01 ( ) INHERITS (measurement); - - - Each of the partitions are complete tables in their own right, - but they inherit their definition from the measurement table. - - - - This solves one of our problems: deleting old data. Each - month, all we need to do is perform a DROP - TABLE on the oldest table and create a new table to - insert into. - - - - - - We now add non-overlapping table constraints, so that our - table creation script becomes: - - -CREATE TABLE measurement_yy04mm02 ( - CHECK ( logdate >= DATE '2004-02-01' AND logdate < DATE '2004-03-01' ) - ) INHERITS (measurement); -CREATE TABLE measurement_yy04mm03 ( - CHECK ( logdate >= DATE '2004-03-01' AND logdate < DATE '2004-04-01' ) - ) INHERITS (measurement); -... -CREATE TABLE measurement_yy05mm11 ( - CHECK ( logdate >= DATE '2005-11-01' AND logdate < DATE '2005-12-01' ) - ) INHERITS (measurement); -CREATE TABLE measurement_yy05mm12 ( - CHECK ( logdate >= DATE '2005-12-01' AND logdate < DATE '2006-01-01' ) - ) INHERITS (measurement); -CREATE TABLE measurement_yy06mm01 ( - CHECK ( logdate >= DATE '2006-01-01' AND logdate < DATE '2006-02-01' ) - ) INHERITS (measurement); - - - - - - - We choose not to add further indexes at this time. - - - - - - Data will be added each day to the latest partition. This - allows us to set up a very simple rule to insert data. We must - redefine this each month so that it always points to the - current partition. - - -CREATE OR REPLACE RULE measurement_current_partition AS -ON INSERT -TO measurement -DO INSTEAD - INSERT INTO measurement_yy06mm01 VALUES ( NEW.city_id, - NEW.logdate, - NEW.peaktemp, - NEW.unitsales ); - - - 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 set of rules as shown below. - - -CREATE RULE measurement_insert_yy04mm02 AS -ON INSERT -TO measurement WHERE - ( logdate >= DATE '2004-02-01' AND logdate < DATE '2004-03-01' ) -DO INSTEAD - INSERT INTO measurement_yy04mm02 VALUES ( NEW.city_id, - NEW.logdate, - NEW.peaktemp, - NEW.unitsales ); -... -CREATE RULE measurement_insert_yy05mm12 AS -ON INSERT -TO measurement WHERE - ( logdate >= DATE '2005-12-01' AND logdate < DATE '2006-01-01' ) -DO INSTEAD - INSERT INTO measurement_yy05mm12 VALUES ( NEW.city_id, - NEW.logdate, - NEW.peaktemp, - NEW.unitsales ); -CREATE RULE measurement_insert_yy06mm01 AS -ON INSERT -TO measurement WHERE - ( logdate >= DATE '2006-01-01' AND logdate < DATE '2006-02-01' ) -DO INSTEAD - INSERT INTO measurement_yy06mm01 VALUES ( NEW.city_id, - NEW.logdate, - NEW.peaktemp, - NEW.unitsales ); - - - Note that the WHERE clause in each rule - exactly matches those used for the CHECK - constraints on each partition. - - - - - - - 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 may be wise to write a - script that generates the required DDL automatically. - - - - The following caveats apply: - - - - There is currently no way to specify that all of the - CHECK constraints are mutually - exclusive. Care is required by the database designer. - - - - - - There is currently no way to specify that rows may not be - inserted into the master table. A CHECK - constraint on the master table will be inherited by all child - tables, so that cannot not be used for this purpose. - - - - - - For some data types you must explicitly coerce the constant - values into the data type of the column. The following constraint - will work if x is an integer - data type, but not if x is a - bigint: - -CHECK ( x = 1 ) - - For bigint we must use a constraint like: - -CHECK ( x = 1::bigint ) - - The problem is not limited to the bigint data type - — it can occur whenever the default data type of the - constant does not match the data type of the column to which it - is being compared. - - - - - - Partitioning can also be arranged using a UNION - ALL view: - - -CREATE VIEW measurement AS - SELECT * FROM measurement_yy04mm02 -UNION ALL SELECT * FROM measurement_yy04mm03 -... -UNION ALL SELECT * FROM measurement_yy05mm11 -UNION ALL SELECT * FROM measurement_yy05mm12 -UNION ALL SELECT * FROM measurement_yy06mm01; - - - However, constraint exclusion is currently not supported for - partitioned tables defined in this manner. - - - - - - - - Constraint Exclusion in Queries - - - Partitioning can be used to improve query performance when used in - conjunction with constraint exclusion. As an example: - - -SET constraint_exclusion=true; -SELECT count(*) FROM measurement WHERE logdate >= DATE '2006-01-01'; - - - Without constraint exclusion, the above query would scan each of - the partitions of the measurement table. With constraint - exclusion, the planner will examine each of the constraints and - try to prove that each of the partitions needs to be involved in - the query. If the planner is able to refute that for any - partition, it excludes the partition from the query plan. - - - - You can use the EXPLAIN command to show the difference - between a plan with constraint_exclusion on and a plan - with it off. - - -SET constraint_exclusion=false; -EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2006-01-01'; - - QUERY PLAN ------------------------------------------------------------------------------------------------ - Aggregate (cost=158.66..158.68 rows=1 width=0) - -> Append (cost=0.00..151.88 rows=2715 width=0) - -> Seq Scan on measurement (cost=0.00..30.38 rows=543 width=0) - Filter: (logdate >= '2006-01-01'::date) - -> Seq Scan on measurement_yy04mm02 measurement (cost=0.00..30.38 rows=543 width=0) - Filter: (logdate >= '2006-01-01'::date) - -> Seq Scan on measurement_yy04mm03 measurement (cost=0.00..30.38 rows=543 width=0) - Filter: (logdate >= '2006-01-01'::date) -... - -> Seq Scan on measurement_yy05mm12 measurement (cost=0.00..30.38 rows=543 width=0) - Filter: (logdate >= '2006-01-01'::date) - -> Seq Scan on measurement_yy06mm01 measurement (cost=0.00..30.38 rows=543 width=0) - Filter: (logdate >= '2006-01-01'::date) - - - Now when we enable constraint exclusion, we get a significantly - reduced plan but the same result set: - - -SET constraint_exclusion=true; -EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2006-01-01'; - QUERY PLAN ------------------------------------------------------------------------------------------------ - Aggregate (cost=63.47..63.48 rows=1 width=0) - -> Append (cost=0.00..60.75 rows=1086 width=0) - -> Seq Scan on measurement (cost=0.00..30.38 rows=543 width=0) - Filter: (logdate >= '2006-01-01'::date) - -> Seq Scan on measurement_yy06mm01 measurement (cost=0.00..30.38 rows=543 width=0) - Filter: (logdate >= '2006-01-01'::date) - - - Don't forget that you still need to run ANALYZE - on each partition individually. A command like this - -ANALYZE measurement; - - - only affects the master table. - - - - No indexes are required to use constraint exclusion. The - partitions should be defined with appropriate CHECK - constraints. These are then compared with the predicates of the - SELECT query to determine which partitions must be - scanned. - - - - The following caveats apply to this release: - - - - Constraint exclusion only works when the query directly matches - a constant. A constant bound to a parameterized query will not - work in the same way since the plan is fixed and would need to - vary with each execution. Also, stable constants such as - CURRENT_DATE may not be used, since these are - constant only for during the execution of a single query. Join - conditions will not allow constraint exclusion to work either. - - - - - - UPDATE and DELETE commands - against the master table do not perform constraint exclusion. - - - - - - All constraints on all partitions of the master table are considered for - constraint exclusion, so large numbers of partitions are likely to - increase query planning time considerably. - - - - - - - - - - Modifying Tables @@ -2712,6 +1874,870 @@ REVOKE CREATE ON SCHEMA public FROM PUBLIC; + + Inheritance + + + inheritance + + + + table + inheritance + + + + PostgreSQL implements table inheritance + which can be a useful tool for database designers. (SQL:1999 and + later define a type inheritance feature, which differs in many + respects from the features described here.) + + + + Let's start with an example: suppose we are trying to build a data + model for cities. Each state has many cities, but only one + capital. We want to be able to quickly retrieve the capital city + for any particular state. This can be done by creating two tables, + one for state capitals and one for cities that are not + capitals. However, what happens when we want to ask for data about + a city, regardless of whether it is a capital or not? The + inheritance feature can help to resolve this problem. We define the + capitals table so that it inherits from + cities: + + +CREATE TABLE cities ( + name text, + population float, + altitude int -- in feet +); + +CREATE TABLE capitals ( + state char(2) +) INHERITS (cities); + + + In this case, the capitals table inherits + all the columns of its parent table, cities. State + capitals also have an extra column, state, that shows + their state. + + + + In PostgreSQL, a table can inherit from + zero or more other tables, and a query can reference either all + rows of a table or all rows of a table plus all of its descendant tables. + The latter behavior is the default. + For example, the following query finds the names of all cities, + including state capitals, that are located at an altitude over + 500ft: + + +SELECT name, altitude + FROM cities + WHERE altitude > 500; + + + Given the sample data from the PostgreSQL + tutorial (see ), this returns: + + + name | altitude +-----------+---------- + Las Vegas | 2174 + Mariposa | 1953 + Madison | 845 + + + + + On the other hand, the following query finds all the cities that + are not state capitals and are situated at an altitude over 500ft: + + +SELECT name, altitude + FROM ONLY cities + WHERE altitude > 500; + + name | altitude +-----------+---------- + Las Vegas | 2174 + Mariposa | 1953 + + + + + Here the ONLY keyword indicates that the query + should apply only to cities, and not any tables + below cities in the inheritance hierarchy. Many + of the commands that we have already discussed — + SELECT, UPDATE and + DELETE — support the + ONLY keyword. + + + + In some cases you may wish to know which table a particular row + originated from. There is a system column called + tableoid in each table which can tell you the + originating table: + + +SELECT c.tableoid, c.name, c.altitude +FROM cities c +WHERE c.altitude > 500; + + + which returns: + + + tableoid | name | altitude +----------+-----------+---------- + 139793 | Las Vegas | 2174 + 139793 | Mariposa | 1953 + 139798 | Madison | 845 + + + (If you try to reproduce this example, you will probably get + different numeric OIDs.) By doing a join with + pg_class you can see the actual table names: + + +SELECT p.relname, c.name, c.altitude +FROM cities c, pg_class p +WHERE c.altitude > 500 and c.tableoid = p.oid; + + + which returns: + + + relname | name | altitude +----------+-----------+---------- + cities | Las Vegas | 2174 + cities | Mariposa | 1953 + capitals | Madison | 845 + + + + + Inheritance does not automatically propagate data from + INSERT or COPY commands to + other tables in the inheritance hierarchy. In our example, the + following INSERT statement will fail: + +INSERT INTO cities (name, population, altitude, state) +VALUES ('New York', NULL, NULL, 'NY'); + + We might hope that the data would somehow be routed to the + capitals table, but this does not happen: + INSERT always inserts into exactly the table + specified. In some cases it is possible to redirect the insertion + using a rule (see ). However that does not + help for the above case because the cities table + does not contain the column state, and so the + command will be rejected before the rule can be applied. + + + + Check constraints can be defined on tables within an inheritance + hierarchy. All check constraints on a parent table are + automatically inherited by all of its children. Other types of + constraints are not inherited, however. + + + + A table can inherit from more than one parent table, in which case it has + the union of the columns defined by the parent tables. Any columns + declared in the child table's definition are added to these. If the + same column name appears in multiple parent tables, or in both a parent + table and the child's definition, then these columns are merged + so that there is only one such column in the child table. To be merged, + columns must have the same data types, else an error is raised. The + merged column will have copies of all the check constraints coming from + any one of the column definitions it came from. + + + + Table inheritance can currently only be defined using the + statement. The related statement CREATE TABLE AS does + not allow inheritance to be specified. There + is no way to add an inheritance link to make an existing table into + a child table. Similarly, there is no way to remove an inheritance + link from a child table once it has been defined, other than by dropping + the table completely. A parent table cannot be dropped + while any of its children remain. If you wish to remove a table and + all of its descendants, one easy way is to drop the parent table with + the CASCADE option. + + + + will + propagate any changes in column data definitions and check + constraints down the inheritance hierarchy. Again, dropping + columns or constraints on parent tables is only possible when using + the CASCADE option. ALTER + TABLE follows the same rules for duplicate column merging + and rejection that apply during CREATE TABLE. + + + + Caveats + + + Table access permissions are not automatically inherited. Therefore, + a user attempting to access a parent table must either have permissions + to do the operation on all its child tables as well, or must use the + ONLY notation. When adding a new child table to + an existing inheritance hierarchy, be careful to grant all the needed + permissions on it. + + + + A serious limitation of the inheritance feature is that indexes (including + unique constraints) and foreign key constraints only apply to single + tables, not to their inheritance children. This is true on both the + referencing and referenced sides of a foreign key constraint. Thus, + in the terms of the above example: + + + + + If we declared cities.name to be + UNIQUE or a PRIMARY KEY, this would not stop the + capitals table from having rows with names duplicating + rows in cities. And those duplicate rows would by + default show up in queries from cities. In fact, by + default capitals would have no unique constraint at all, + and so could contain multiple rows with the same name. + You could add a unique constraint to capitals, but this + would not prevent duplication compared to cities. + + + + + + Similarly, if we were to specify that + cities.name REFERENCES some + other table, this constraint would not automatically propagate to + capitals. In this case you could work around it by + manually adding the same REFERENCES constraint to + capitals. + + + + + + Specifying that another table's column REFERENCES + cities(name) would allow the other table to contain city names, but + not capital names. There is no good workaround for this case. + + + + + These deficiencies will probably be fixed in some future release, + but in the meantime considerable care is needed in deciding whether + inheritance is useful for your problem. + + + + Deprecated + + In previous versions of PostgreSQL, the + default behavior was not to include child tables in queries. This was + found to be error prone and is also in violation of the SQL + standard. Under the old syntax, to include the child tables you append + * to the table name. For example: + +SELECT * from cities*; + + You can still explicitly specify scanning child tables by + appending *, as well as explicitly specify not + scanning child tables by writing ONLY. But + beginning in version 7.1, the default behavior for an undecorated + table name is to scan its child tables too, whereas before the + default was not to do so. To get the old default behavior, + disable the configuration + option. + + + + + + + + Partitioning + + + partitioning + + + + table + partitioning + + + + PostgreSQL supports basic table + partitioning. This section describes why and how you can implement + partitioning as part of your database design. + + + + 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 for certain kinds + of queries. + + + + + + Update performance can be improved too, since each piece of the table + has indexes smaller than an index on the entire data set would be. + When an index no longer fits easily + in memory, both read and write operations on the index take + progressively more disk accesses. + + + + + + Bulk deletes may be accomplished by simply removing one of the + partitions, if that requirement is planned into the partitioning design. + DROP TABLE is far faster than a bulk DELETE, + to say nothing of the ensuing VACUUM overhead. + + + + + + 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. + + + + Currently, PostgreSQL supports partitioning + via table inheritance. 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 implement partitioning. + + + + The following forms of partitioning can be implemented in + PostgreSQL: + + + + 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. + + + + + + Hash partitioning is not currently supported. + + + + + Implementing Partitioning + + + To set up a partitioned table, 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. + + + + + + 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. + + + + We will refer to the child tables as partitions, though they + are in every way normal PostgreSQL tables. + + + + + + Add 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 this: + +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. + + + + Note that there is no difference in + syntax between range and list partitioning; those terms are + descriptive only. + + + + + + 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.) + + + + + + Optionally, define a rule or trigger to redirect modifications + of the master table to the appropriate partition. + + + + + + Ensure that the + configuration + parameter is enabled in postgresql.conf. Without + this, queries will not be optimized as desired. + + + + + + + + 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 this: + + +CREATE TABLE measurement ( + city_id int not null, + logdate date not null, + peaktemp int, + unitsales int +); + + + 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. Following the + steps outlined above, partitioning can be set up as follows: + + + + + + + The master table is the measurement table, declared + exactly as above. + + + + + + Next we create one partition for each active month: + + +CREATE TABLE measurement_yy04mm02 ( ) INHERITS (measurement); +CREATE TABLE measurement_yy04mm03 ( ) INHERITS (measurement); +... +CREATE TABLE measurement_yy05mm11 ( ) INHERITS (measurement); +CREATE TABLE measurement_yy05mm12 ( ) INHERITS (measurement); +CREATE TABLE measurement_yy06mm01 ( ) INHERITS (measurement); + + + Each of the partitions are complete tables in their own right, + but they inherit their definition from the + measurement table. + + + + 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. + + + + + + We must add non-overlapping table constraints, so that our + table creation script becomes: + + +CREATE TABLE measurement_yy04mm02 ( + CHECK ( logdate >= DATE '2004-02-01' AND logdate < DATE '2004-03-01' ) +) INHERITS (measurement); +CREATE TABLE measurement_yy04mm03 ( + CHECK ( logdate >= DATE '2004-03-01' AND logdate < DATE '2004-04-01' ) +) INHERITS (measurement); +... +CREATE TABLE measurement_yy05mm11 ( + CHECK ( logdate >= DATE '2005-11-01' AND logdate < DATE '2005-12-01' ) +) INHERITS (measurement); +CREATE TABLE measurement_yy05mm12 ( + CHECK ( logdate >= DATE '2005-12-01' AND logdate < DATE '2006-01-01' ) +) INHERITS (measurement); +CREATE TABLE measurement_yy06mm01 ( + CHECK ( logdate >= DATE '2006-01-01' AND logdate < DATE '2006-02-01' ) +) INHERITS (measurement); + + + + + + + We probably need indexes on the key columns too: + + +CREATE INDEX measurement_yy04mm02_logdate ON measurement_yy04mm02 (logdate); +CREATE INDEX measurement_yy04mm03_logdate ON measurement_yy04mm03 (logdate); +... +CREATE INDEX measurement_yy05mm11_logdate ON measurement_yy05mm11 (logdate); +CREATE INDEX measurement_yy05mm12_logdate ON measurement_yy05mm12 (logdate); +CREATE INDEX measurement_yy06mm01_logdate ON measurement_yy06mm01 (logdate); + + + We choose not to add further indexes at this time. + + + + + + If data will be added only to the latest partition, we can + set up a very simple rule to insert data. We must + redefine this each month so that it always points to the + current partition. + + +CREATE OR REPLACE RULE measurement_current_partition AS +ON INSERT TO measurement +DO INSTEAD + INSERT INTO measurement_yy06mm01 VALUES ( NEW.city_id, + NEW.logdate, + NEW.peaktemp, + NEW.unitsales ); + + + 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 set of rules as shown below. + + +CREATE RULE measurement_insert_yy04mm02 AS +ON INSERT TO measurement WHERE + ( logdate >= DATE '2004-02-01' AND logdate < DATE '2004-03-01' ) +DO INSTEAD + INSERT INTO measurement_yy04mm02 VALUES ( NEW.city_id, + NEW.logdate, + NEW.peaktemp, + NEW.unitsales ); +... +CREATE RULE measurement_insert_yy05mm12 AS +ON INSERT TO measurement WHERE + ( logdate >= DATE '2005-12-01' AND logdate < DATE '2006-01-01' ) +DO INSTEAD + INSERT INTO measurement_yy05mm12 VALUES ( NEW.city_id, + NEW.logdate, + NEW.peaktemp, + NEW.unitsales ); +CREATE RULE measurement_insert_yy06mm01 AS +ON INSERT TO measurement WHERE + ( logdate >= DATE '2006-01-01' AND logdate < DATE '2006-02-01' ) +DO INSTEAD + INSERT INTO measurement_yy06mm01 VALUES ( NEW.city_id, + NEW.logdate, + NEW.peaktemp, + NEW.unitsales ); + + + Note that the WHERE clause in each rule + exactly matches the the CHECK + constraint for its partition. + + + + + + + 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 may be wise to write a + script that generates the required DDL automatically. + + + + The following caveats apply: + + + + There is currently no way to verify that all of the + CHECK constraints are mutually + exclusive. Care is required by the database designer. + + + + + + There is currently no simple way to specify that rows must not be + inserted into the master table. A CHECK (false) + constraint on the master table would be inherited by all child + tables, so that cannot be used for this purpose. One possibility is + to set up an ON INSERT trigger on the master table that + always raises an error. (Alternatively, such a trigger could be + used to redirect the data into the proper child table, instead of + using a set of rules as suggested above.) + + + + + + + Partitioning can also be arranged using a UNION ALL + view: + + +CREATE VIEW measurement AS + SELECT * FROM measurement_yy04mm02 +UNION ALL SELECT * FROM measurement_yy04mm03 +... +UNION ALL SELECT * FROM measurement_yy05mm11 +UNION ALL SELECT * FROM measurement_yy05mm12 +UNION ALL SELECT * FROM measurement_yy06mm01; + + + However, constraint exclusion is currently not supported for + partitioned tables defined in this manner. Also, the need to + recreate the view adds an extra step to adding and dropping + individual partitions of the dataset. + + + + + Partitioning and Constraint Exclusion + + + constraint exclusion + + + + Constraint exclusion is a query optimization technique + that improves performance for partitioned tables defined in the + fashion described above. As an example: + + +SET constraint_exclusion = on; +SELECT count(*) FROM measurement WHERE logdate >= DATE '2006-01-01'; + + + Without constraint exclusion, the above query would scan each of + the partitions of the measurement table. With constraint + exclusion enabled, the planner will examine the constraints of each + partition and try to prove that the partition need not + be scanned because it could not contain any rows meeting the query's + WHERE clause. When the planner can prove this, it + excludes the partition from the query plan. + + + + You can use the EXPLAIN command to show the difference + between a plan with constraint_exclusion on and a plan + with it off. A typical default plan for this type of table setup is: + + +SET constraint_exclusion = off; +EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2006-01-01'; + + QUERY PLAN +----------------------------------------------------------------------------------------------- + Aggregate (cost=158.66..158.68 rows=1 width=0) + -> Append (cost=0.00..151.88 rows=2715 width=0) + -> Seq Scan on measurement (cost=0.00..30.38 rows=543 width=0) + Filter: (logdate >= '2006-01-01'::date) + -> Seq Scan on measurement_yy04mm02 measurement (cost=0.00..30.38 rows=543 width=0) + Filter: (logdate >= '2006-01-01'::date) + -> Seq Scan on measurement_yy04mm03 measurement (cost=0.00..30.38 rows=543 width=0) + Filter: (logdate >= '2006-01-01'::date) +... + -> Seq Scan on measurement_yy05mm12 measurement (cost=0.00..30.38 rows=543 width=0) + Filter: (logdate >= '2006-01-01'::date) + -> Seq Scan on measurement_yy06mm01 measurement (cost=0.00..30.38 rows=543 width=0) + Filter: (logdate >= '2006-01-01'::date) + + + Some or all of the partitions might use index scans instead of + full-table sequential scans, but the point here is that there + is no need to scan the older partitions at all to answer this query. + When we enable constraint exclusion, we get a significantly + reduced plan that will deliver the same answer: + + +SET constraint_exclusion = on; +EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2006-01-01'; + QUERY PLAN +----------------------------------------------------------------------------------------------- + Aggregate (cost=63.47..63.48 rows=1 width=0) + -> Append (cost=0.00..60.75 rows=1086 width=0) + -> Seq Scan on measurement (cost=0.00..30.38 rows=543 width=0) + Filter: (logdate >= '2006-01-01'::date) + -> Seq Scan on measurement_yy06mm01 measurement (cost=0.00..30.38 rows=543 width=0) + Filter: (logdate >= '2006-01-01'::date) + + + + + Note that constraint exclusion is driven only by CHECK + constraints, not by the presence of indexes. Therefore it isn't + necessary to define indexes on the key columns. Whether an index + needs to be created for a given partition depends on whether you + expect that queries that scan the partition will generally scan + a large part of the partition or just a small part. An index will + be helpful in the latter case but not the former. + + + + The following caveats apply: + + + + + Constraint exclusion only works when the query's WHERE + clause contains constants. A parameterized query will not be + optimized, since the planner cannot know what partitions the + parameter value might select at runtime. For the same reason, + stable functions such as CURRENT_DATE + must be avoided. Joining the partition key to a column of another + table will not be optimized, either. + + + + + + Avoid cross-datatype comparisons in the CHECK + constraints, as the planner will currently fail to prove such + conditions false. For example, the following constraint + will work if x is an integer + column, but not if x is a + bigint: + +CHECK ( x = 1 ) + + For a bigint column we must use a constraint like: + +CHECK ( x = 1::bigint ) + + The problem is not limited to the bigint data type + — it can occur whenever the default data type of the + constant does not match the data type of the column to which it + is being compared. Cross-datatype comparisons in the supplied + queries are usually OK, just not in the CHECK conditions. + + + + + + UPDATE and DELETE commands + against the master table do not currently perform constraint exclusion. + + + + + + All constraints on all partitions of the master table are considered for + constraint exclusion, so large numbers of partitions are likely to + increase query planning time considerably. + + + + + + Don't forget that you still need to run ANALYZE + on each partition individually. A command like + +ANALYZE measurement; + + will only process the master table. + + + + + + + + Other Database Objects @@ -2798,7 +2824,7 @@ DROP TABLE products CASCADE; and all the dependent objects will be removed. In this case, it doesn't remove the orders table, it only removes the foreign key - constraint. (If you want to check what DROP ... CASCADE will do, + constraint. (If you want to check what DROP ... CASCADE will do, run DROP without CASCADE and read the NOTICE messages.)