September 26, 2024: PostgreSQL 17 Released!
Unsupported versions: 7.1
This documentation is for an unsupported version of PostgreSQL.
You may want to view the same page for the current version, or one of the other supported versions listed above instead.

Chapter 5. Advanced Postgres SQL Features

Table of Contents
5.1. Inheritance
5.2. Non-Atomic Values
5.3. More Advanced Features

Having covered the basics of using Postgres SQL to access your data, we will now discuss those features of Postgres that distinguish it from conventional data managers. These features include inheritance, time travel and non-atomic data values (array- and set-valued attributes). Examples in this section can also be found in advance.sql in the tutorial directory. (Refer to Chapter 4 for how to use it.)

5.1. Inheritance

Let's create two tables. The capitals table contains state capitals that are also cities. Naturally, the capitals table should inherit from cities.

CREATE TABLE cities (
    name            text,
    population      real,
    altitude        int     -- (in ft)
);

CREATE TABLE capitals (
    state           char(2)
) INHERITS (cities);
    
In this case, a row of capitals inherits all columns (name, population, and altitude) from its parent, cities. The type of the column name is text, a native Postgres type for variable length ASCII strings. The type of the column population is real, a type for single precision floating point numbers. State capitals have an extra column, state, that shows their state. In Postgres, 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 tables plus all of its descendants.

Note: The inheritance hierarchy is 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 of 500ft or higher:

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 the cities table, 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.

Deprecated: In previous versions of Postgres, the default was not to get access to child tables. This was found to be error prone and is also in violation of SQL99. 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.