File: ddl-inherit.html

package info (click to toggle)
pgadmin3 1.4.3-2
  • links: PTS
  • area: main
  • in suites: etch, etch-m68k
  • size: 29,796 kB
  • ctags: 10,758
  • sloc: cpp: 55,356; sh: 6,164; ansic: 1,520; makefile: 576; sql: 482; xml: 100; perl: 18
file content (257 lines) | stat: -rw-r--r-- 12,437 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>5.8.Inheritance</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="ddl.html" title="Chapter5.Data Definition">
<link rel="prev" href="ddl-schemas.html" title="5.7.Schemas">
<link rel="next" href="ddl-partitioning.html" title="5.9.Partitioning">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="ddl-inherit"></a>5.8.Inheritance</h2></div></div></div>
<a name="id577757"></a><a name="id577763"></a><p>   <span class="productname">PostgreSQL</span> 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.)
  </p>
<p>   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
   <code class="structname">capitals</code> table so that it inherits from
   <code class="structname">cities</code>:

</p>
<pre class="programlisting">CREATE TABLE cities (
    name            text,
    population      float,
    altitude        int     -- in feet
);

CREATE TABLE capitals (
    state           char(2)
) INHERITS (cities);</pre>
<p>

   In this case, the <code class="structname">capitals</code> table <em class="firstterm">inherits</em>
   all the columns of its parent table, <code class="structname">cities</code>. State
   capitals also have an extra column, <code class="structfield">state</code>, that shows
   their state.
  </p>
<p>   In <span class="productname">PostgreSQL</span>, 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:

</p>
<pre class="programlisting">SELECT name, altitude
    FROM cities
    WHERE altitude &gt; 500;</pre>
<p>

   Given the sample data from the <span class="productname">PostgreSQL</span>
   tutorial (see <a href="tutorial-sql.html#tutorial-sql-intro" title="2.1.Introduction">Section2.1, &#8220;Introduction&#8221;</a>), this returns:

</p>
<pre class="programlisting">   name    | altitude
-----------+----------
 Las Vegas |     2174
 Mariposa  |     1953
 Madison   |      845</pre>
<p>
  </p>
<p>   On the other hand, the following query finds all the cities that
   are not state capitals and are situated at an altitude over 500ft:

</p>
<pre class="programlisting">SELECT name, altitude
    FROM ONLY cities
    WHERE altitude &gt; 500;

   name    | altitude
-----------+----------
 Las Vegas |     2174
 Mariposa  |     1953</pre>
<p>
  </p>
<p>   Here the <code class="literal">ONLY</code> keyword indicates that the query
   should apply only to <code class="structname">cities</code>, and not any tables
   below <code class="structname">cities</code> in the inheritance hierarchy.  Many
   of the commands that we have already discussed [mdash ]
   <code class="command">SELECT</code>, <code class="command">UPDATE</code> and
   <code class="command">DELETE</code> [mdash ] support the
   <code class="literal">ONLY</code> keyword.
  </p>
<p>   In some cases you may wish to know which table a particular row
   originated from. There is a system column called
   <code class="structfield">tableoid</code> in each table which can tell you the
   originating table:

</p>
<pre class="programlisting">SELECT c.tableoid, c.name, c.altitude
FROM cities c
WHERE c.altitude &gt; 500;</pre>
<p>

   which returns:

</p>
<pre class="programlisting"> tableoid |   name    | altitude
----------+-----------+----------
   139793 | Las Vegas |     2174
   139793 | Mariposa  |     1953
   139798 | Madison   |      845</pre>
<p>

   (If you try to reproduce this example, you will probably get
   different numeric OIDs.)  By doing a join with
   <code class="structname">pg_class</code> you can see the actual table names:

</p>
<pre class="programlisting">SELECT p.relname, c.name, c.altitude
FROM cities c, pg_class p
WHERE c.altitude &gt; 500 and c.tableoid = p.oid;</pre>
<p>

   which returns:

</p>
<pre class="programlisting"> relname  |   name    | altitude
----------+-----------+----------
 cities   | Las Vegas |     2174
 cities   | Mariposa  |     1953
 capitals | Madison   |      845</pre>
<p>
  </p>
<p>   Inheritance does not automatically propagate data from
   <code class="command">INSERT</code> or <code class="command">COPY</code> commands to
   other tables in the inheritance hierarchy. In our example, the
   following <code class="command">INSERT</code> statement will fail:
</p>
<pre class="programlisting">INSERT INTO cities (name, population, altitude, state)
VALUES ('New York', NULL, NULL, 'NY');</pre>
<p>
   We might hope that the data would somehow be routed to the
   <code class="structname">capitals</code> table, but this does not happen:
   <code class="command">INSERT</code> always inserts into exactly the table
   specified.  In some cases it is possible to redirect the insertion
   using a rule (see <a href="rules.html" title="Chapter34.The Rule System">Chapter34, <i>The Rule System</i></a>).  However that does not
   help for the above case because the <code class="structname">cities</code> table
   does not contain the column <code class="structfield">state</code>, and so the
   command will be rejected before the rule can be applied.
  </p>
<p>   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.
  </p>
<p>   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 &#8220;<span class="quote">merged</span>&#8221;
   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.
  </p>
<p>   Table inheritance can currently only be defined using the <a href="sql-createtable.html">CREATE TABLE</a>
   statement.  The related statement <code class="command">CREATE TABLE AS</code> 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 <code class="literal">CASCADE</code> option.
  </p>
<p>   <a href="sql-altertable.html">ALTER TABLE</a> 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 <code class="literal">CASCADE</code> option. <code class="command">ALTER
   TABLE</code> follows the same rules for duplicate column merging
   and rejection that apply during <code class="command">CREATE TABLE</code>.
  </p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-inherit-caveats"></a>5.8.1.Caveats</h3></div></div></div>
<p>   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
   <code class="literal">ONLY</code> notation.  When adding a new child table to
   an existing inheritance hierarchy, be careful to grant all the needed
   permissions on it.
  </p>
<p>   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:

   </p>
<div class="itemizedlist"><ul type="disc">
<li><p>      If we declared <code class="structname">cities</code>.<code class="structfield">name</code> to be
      <code class="literal">UNIQUE</code> or a <code class="literal">PRIMARY KEY</code>, this would not stop the
      <code class="structname">capitals</code> table from having rows with names duplicating
      rows in <code class="structname">cities</code>.  And those duplicate rows would by
      default show up in queries from <code class="structname">cities</code>.  In fact, by
      default <code class="structname">capitals</code> would have no unique constraint at all,
      and so could contain multiple rows with the same name.
      You could add a unique constraint to <code class="structname">capitals</code>, but this
      would not prevent duplication compared to <code class="structname">cities</code>.
     </p></li>
<li><p>      Similarly, if we were to specify that
      <code class="structname">cities</code>.<code class="structfield">name</code> <code class="literal">REFERENCES</code> some
      other table, this constraint would not automatically propagate to
      <code class="structname">capitals</code>.  In this case you could work around it by
      manually adding the same <code class="literal">REFERENCES</code> constraint to
      <code class="structname">capitals</code>.
     </p></li>
<li><p>      Specifying that another table's column <code class="literal">REFERENCES
      cities(name)</code> would allow the other table to contain city names, but
      not capital names.  There is no good workaround for this case.
     </p></li>
</ul></div>
<p>

   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.
  </p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Deprecated</h3>
<p>     In previous versions of <span class="productname">PostgreSQL</span>, 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
     <code class="literal">*</code> to the table name. For example:
</p>
<pre class="programlisting">SELECT * from cities*;</pre>
<p>
     You can still explicitly specify scanning child tables by
     appending <code class="literal">*</code>, as well as explicitly specify not
     scanning child tables by writing <code class="literal">ONLY</code>.  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 <a href="runtime-config-compatible.html#guc-sql-inheritance">sql_inheritance</a> configuration
     option.
   </p>
</div>
</div>
</div></body>
</html>