Documentation
 
 
 

4.9. Inheritance

EnterpriseDB 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: we have 3 sample tables, emp , dept , jobhist . Let us suppose there are some directors in the organization as well. Now we know that every director is an employee but not every employee is a director. Suppose every director receives an extra allowance. We want to be able to quickly retrieve the data for any particular director. This can be done by creating two tables, one for directors and one for employees that are not directors. However, what happens when we want to ask for data about an employee, regardless of whether he is a director or not? The inheritance feature can help to resolve this problem. We define the director table so that it inherits from emp:

CREATE TABLE director (

   director_allowance NUMBER (10)

) INHERITS (emp);

INSERT INTO director VALUES (8002,'ALEX','DIRECTOR',7839,'23-DEC-81',3000,NULL,20,1000);
INSERT INTO director VALUES (8008,'KENNETH','DIRECTOR',7839,'01-AUG-81',3850,NULL,30,1500);
INSERT INTO director VALUES (7009,'RON','DIRECTOR',7839,'17-OCT-81',4000,NULL,10,2500);

In this case, the director table inherits all the columns of its parent table, emp. Along with that, director table also has an extra column, allowance that shows the allowance each director receives.

In EnterpriseDB, 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 employees, including directors, that receive a salary of over 1500:

SELECT ename, sal 
    FROM emp
    WHERE sal > 1500;

After running this query we should see the followin output:

  ename  |   sal
---------+---------
 ALLEN   | 1600.00
 JONES   | 2975.00
 BLAKE   | 2850.00
 CLARK   | 2450.00
 SCOTT   | 3000.00
 KING    | 5000.00
 FORD    | 3000.00
 ALEX    | 3000.00
 KENNETH | 3850.00
 RON     | 4000.00
(10 rows)

On the other hand, the following query finds all the employees that are not directors and receive a salary of over 1500.

SELECT ename, sal 
    FROM ONLY emp
    WHERE sal > 1500;

 ename |   sal
-------+---------
 ALLEN | 1600.00
 JONES | 2975.00
 BLAKE | 2850.00
 CLARK | 2450.00
 SCOTT | 3000.00
 KING  | 5000.00
 FORD  | 3000.00
(7 rows)

Here the ONLY keyword indicates that the query should apply only to emp, and not any tables below emp 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 e.tableoid, e.ename, e.sal
FROM emp e
WHERE e.sal > 1500;

which returns:

 tableoid |  ename  |   sal
----------+---------+---------
    16460 | ALLEN   | 1600.00
    16460 | JONES   | 2975.00
    16460 | BLAKE   | 2850.00
    16460 | CLARK   | 2450.00
    16460 | SCOTT   | 3000.00
    16460 | KING    | 5000.00
    16460 | FORD    | 3000.00
    16473 | ALEX    | 3000.00
    16473 | KENNETH | 3850.00
    16473 | RON     | 4000.00
(10 rows)

(10 rows)

(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, e.ename, e.sal
FROM emp e, pg_class p
WHERE e.sal > 1500 and e.tableoid = p.oid;

which returns:

 relname  |  ename  |   sal
----------+---------+---------
 emp      | ALLEN   | 1600.00
 emp      | JONES   | 2975.00
 emp      | BLAKE   | 2850.00
 emp      | CLARK   | 2450.00
 emp      | SCOTT   | 3000.00
 emp      | KING    | 5000.00
 emp      | FORD    | 3000.00
 director | ALEX    | 3000.00
 director | KENNETH | 3850.00
 director | RON     | 4000.00
(10 rows)

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 emp (empno, ename, job, mgr, hiredate, sal, comm, deptno, director_allowance)
VALUES (7934, NULL, NULL, NULL, NULL, NULL, NULL, NULL, 1000);

We might hope that the data would somehow be routed to the director 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 Chapter 12). However that does not help for the above case because the emp table does not contain the column director_allowance, 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 CREATE TABLE 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.

ALTER TABLE 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.

4.9.1. 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:

  • We have declared emp.empno to be UNIQUE or a PRIMARY KEY, this would not stop the director table from having rows with names duplicating rows in emp. And those duplicate rows would by default show up in queries from emp. In fact, by default director would have no unique constraint at all, and so could contain multiple rows with the same name. You could add a unique constraint to director, but this would not prevent duplication compared to emp.

  • Similarly, if we were to specify that emp.empno REFERENCES some other table, this constraint would not automatically propagate to director. In this case you could work around it by manually adding the same REFERENCES constraint to director.

  • Specifying that another table's column REFERENCES emp(empno) would allow the other table to contain employee ids, but not director ids. 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.

 
 ©2004-2007 EnterpriseDB All Rights Reserved