6 PostgreSQL implements table inheritance, which can be a useful tool for
7 database designers. (SQL:1999 and later define a type inheritance
8 feature, which differs in many respects from the features described
11 Let's start with an example: suppose we are trying to build a data
12 model for cities. Each state has many cities, but only one capital. We
13 want to be able to quickly retrieve the capital city for any particular
14 state. This can be done by creating two tables, one for state capitals
15 and one for cities that are not capitals. However, what happens when we
16 want to ask for data about a city, regardless of whether it is a
17 capital or not? The inheritance feature can help to resolve this
18 problem. We define the capitals table so that it inherits from cities:
22 elevation int -- in feet
25 CREATE TABLE capitals (
29 In this case, the capitals table inherits all the columns of its parent
30 table, cities. State capitals also have an extra column, state, that
33 In PostgreSQL, a table can inherit from zero or more other tables, and
34 a query can reference either all rows of a table or all rows of a table
35 plus all of its descendant tables. The latter behavior is the default.
36 For example, the following query finds the names of all cities,
37 including state capitals, that are located at an elevation over 500
39 SELECT name, elevation
41 WHERE elevation > 500;
43 Given the sample data from the PostgreSQL tutorial (see Section 2.1),
46 -----------+-----------
51 On the other hand, the following query finds all the cities that are
52 not state capitals and are situated at an elevation over 500 feet:
53 SELECT name, elevation
55 WHERE elevation > 500;
58 -----------+-----------
62 Here the ONLY keyword indicates that the query should apply only to
63 cities, and not any tables below cities in the inheritance hierarchy.
64 Many of the commands that we have already discussed — SELECT, UPDATE
65 and DELETE — support the ONLY keyword.
67 You can also write the table name with a trailing * to explicitly
68 specify that descendant tables are included:
69 SELECT name, elevation
71 WHERE elevation > 500;
73 Writing * is not necessary, since this behavior is always the default.
74 However, this syntax is still supported for compatibility with older
75 releases where the default could be changed.
77 In some cases you might wish to know which table a particular row
78 originated from. There is a system column called tableoid in each table
79 which can tell you the originating table:
80 SELECT c.tableoid, c.name, c.elevation
82 WHERE c.elevation > 500;
85 tableoid | name | elevation
86 ----------+-----------+-----------
87 139793 | Las Vegas | 2174
88 139793 | Mariposa | 1953
89 139798 | Madison | 845
91 (If you try to reproduce this example, you will probably get different
92 numeric OIDs.) By doing a join with pg_class you can see the actual
94 SELECT p.relname, c.name, c.elevation
95 FROM cities c, pg_class p
96 WHERE c.elevation > 500 AND c.tableoid = p.oid;
99 relname | name | elevation
100 ----------+-----------+-----------
101 cities | Las Vegas | 2174
102 cities | Mariposa | 1953
103 capitals | Madison | 845
105 Another way to get the same effect is to use the regclass alias type,
106 which will print the table OID symbolically:
107 SELECT c.tableoid::regclass, c.name, c.elevation
109 WHERE c.elevation > 500;
111 Inheritance does not automatically propagate data from INSERT or COPY
112 commands to other tables in the inheritance hierarchy. In our example,
113 the following INSERT statement will fail:
114 INSERT INTO cities (name, population, elevation, state)
115 VALUES ('Albany', NULL, NULL, 'NY');
117 We might hope that the data would somehow be routed to the capitals
118 table, but this does not happen: INSERT always inserts into exactly the
119 table specified. In some cases it is possible to redirect the insertion
120 using a rule (see Chapter 39). However that does not help for the above
121 case because the cities table does not contain the column state, and so
122 the command will be rejected before the rule can be applied.
124 All check constraints and not-null constraints on a parent table are
125 automatically inherited by its children, unless explicitly specified
126 otherwise with NO INHERIT clauses. Other types of constraints (unique,
127 primary key, and foreign key constraints) are not inherited.
129 A table can inherit from more than one parent table, in which case it
130 has the union of the columns defined by the parent tables. Any columns
131 declared in the child table's definition are added to these. If the
132 same column name appears in multiple parent tables, or in both a parent
133 table and the child's definition, then these columns are “merged” so
134 that there is only one such column in the child table. To be merged,
135 columns must have the same data types, else an error is raised.
136 Inheritable check constraints and not-null constraints are merged in a
137 similar fashion. Thus, for example, a merged column will be marked
138 not-null if any one of the column definitions it came from is marked
139 not-null. Check constraints are merged if they have the same name, and
140 the merge will fail if their conditions are different.
142 Table inheritance is typically established when the child table is
143 created, using the INHERITS clause of the CREATE TABLE statement.
144 Alternatively, a table which is already defined in a compatible way can
145 have a new parent relationship added, using the INHERIT variant of
146 ALTER TABLE. To do this the new child table must already include
147 columns with the same names and types as the columns of the parent. It
148 must also include check constraints with the same names and check
149 expressions as those of the parent. Similarly an inheritance link can
150 be removed from a child using the NO INHERIT variant of ALTER TABLE.
151 Dynamically adding and removing inheritance links like this can be
152 useful when the inheritance relationship is being used for table
153 partitioning (see Section 5.12).
155 One convenient way to create a compatible table that will later be made
156 a new child is to use the LIKE clause in CREATE TABLE. This creates a
157 new table with the same columns as the source table. If there are any
158 CHECK constraints defined on the source table, the INCLUDING
159 CONSTRAINTS option to LIKE should be specified, as the new child must
160 have constraints matching the parent to be considered compatible.
162 A parent table cannot be dropped while any of its children remain.
163 Neither can columns or check constraints of child tables be dropped or
164 altered if they are inherited from any parent tables. If you wish to
165 remove a table and all of its descendants, one easy way is to drop the
166 parent table with the CASCADE option (see Section 5.15).
168 ALTER TABLE will propagate any changes in column data definitions and
169 check constraints down the inheritance hierarchy. Again, dropping
170 columns that are depended on by other tables is only possible when
171 using the CASCADE option. ALTER TABLE follows the same rules for
172 duplicate column merging and rejection that apply during CREATE TABLE.
174 Inherited queries perform access permission checks on the parent table
175 only. Thus, for example, granting UPDATE permission on the cities table
176 implies permission to update rows in the capitals table as well, when
177 they are accessed through cities. This preserves the appearance that
178 the data is (also) in the parent table. But the capitals table could
179 not be updated directly without an additional grant. In a similar way,
180 the parent table's row security policies (see Section 5.9) are applied
181 to rows coming from child tables during an inherited query. A child
182 table's policies, if any, are applied only when it is the table
183 explicitly named in the query; and in that case, any policies attached
184 to its parent(s) are ignored.
186 Foreign tables (see Section 5.13) can also be part of inheritance
187 hierarchies, either as parent or child tables, just as regular tables
188 can be. If a foreign table is part of an inheritance hierarchy then any
189 operations not supported by the foreign table are not supported on the
190 whole hierarchy either.
194 Note that not all SQL commands are able to work on inheritance
195 hierarchies. Commands that are used for data querying, data
196 modification, or schema modification (e.g., SELECT, UPDATE, DELETE,
197 most variants of ALTER TABLE, but not INSERT or ALTER TABLE ... RENAME)
198 typically default to including child tables and support the ONLY
199 notation to exclude them. The majority of commands that do database
200 maintenance and tuning (e.g., REINDEX) only work on individual,
201 physical tables and do not support recursing over inheritance
202 hierarchies. However, both VACUUM and ANALYZE commands default to
203 including child tables and the ONLY notation is supported to allow them
204 to be excluded. The respective behavior of each individual command is
205 documented in its reference page (SQL Commands).
207 A serious limitation of the inheritance feature is that indexes
208 (including unique constraints) and foreign key constraints only apply
209 to single tables, not to their inheritance children. This is true on
210 both the referencing and referenced sides of a foreign key constraint.
211 Thus, in the terms of the above example:
212 * If we declared cities.name to be UNIQUE or a PRIMARY KEY, this
213 would not stop the capitals table from having rows with names
214 duplicating rows in cities. And those duplicate rows would by
215 default show up in queries from cities. In fact, by default
216 capitals would have no unique constraint at all, and so could
217 contain multiple rows with the same name. You could add a unique
218 constraint to capitals, but this would not prevent duplication
220 * Similarly, if we were to specify that cities.name REFERENCES some
221 other table, this constraint would not automatically propagate to
222 capitals. In this case you could work around it by manually adding
223 the same REFERENCES constraint to capitals.
224 * Specifying that another table's column REFERENCES cities(name)
225 would allow the other table to contain city names, but not capital
226 names. There is no good workaround for this case.
228 Some functionality not implemented for inheritance hierarchies is
229 implemented for declarative partitioning. Considerable care is needed
230 in deciding whether partitioning with legacy inheritance is useful for