PostgreSQL 7.4.30 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 5. Data Definition | Fast Forward | Next |
Let's create two tables. The capitals table contains state capitals which are also cities. Naturally, the capitals table should inherit from cities.
CREATE TABLE cities ( name text, population float, altitude int -- (in ft) ); CREATE TABLE capitals ( state char(2) ) INHERITS (cities);
In this case, a row of capitals inherits all attributes (name, population, and altitude) from its parent, cities. The type of the attribute name is text, a native PostgreSQL type for variable length character strings. The type of the attribute population is float, a native PostgreSQL type for double precision floating-point numbers. 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.
Note: The inheritance hierarchy is actually a directed acyclic graph.
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" before cities indicates that the query should be run over only cities and not tables below cities in the inheritance hierarchy. Many of the commands that we have already discussed -- SELECT, UPDATE and DELETE -- support this "ONLY" notation.
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
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 SQL99 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, set the configuration option SQL_Inheritance to off, e.g.,
SET SQL_Inheritance TO OFF;or add a line in your postgresql.conf file.
A 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. Thus, in the above example, specifying that another table's column REFERENCES cities(name) would allow the other table to contain city names but not capital names. This deficiency will probably be fixed in some future release.