Fix spelling error in docs.
[PostgreSQL.git] / doc / src / sgml / ddl.sgml
blobd71a1cc262ad408e8299b2279400386246f072cd
1 <!-- $PostgreSQL$ -->
3 <chapter id="ddl">
4 <title>Data Definition</title>
6 <para>
7 This chapter covers how one creates the database structures that
8 will hold one's data. In a relational database, the raw data is
9 stored in tables, so the majority of this chapter is devoted to
10 explaining how tables are created and modified and what features are
11 available to control what data is stored in the tables.
12 Subsequently, we discuss how tables can be organized into
13 schemas, and how privileges can be assigned to tables. Finally,
14 we will briefly look at other features that affect the data storage,
15 such as inheritance, views, functions, and triggers.
16 </para>
18 <sect1 id="ddl-basics">
19 <title>Table Basics</title>
21 <indexterm zone="ddl-basics">
22 <primary>table</primary>
23 </indexterm>
25 <indexterm>
26 <primary>row</primary>
27 </indexterm>
29 <indexterm>
30 <primary>column</primary>
31 </indexterm>
33 <para>
34 A table in a relational database is much like a table on paper: It
35 consists of rows and columns. The number and order of the columns
36 is fixed, and each column has a name. The number of rows is
37 variable &mdash; it reflects how much data is stored at a given moment.
38 SQL does not make any guarantees about the order of the rows in a
39 table. When a table is read, the rows will appear in random order,
40 unless sorting is explicitly requested. This is covered in <xref
41 linkend="queries">. Furthermore, SQL does not assign unique
42 identifiers to rows, so it is possible to have several completely
43 identical rows in a table. This is a consequence of the
44 mathematical model that underlies SQL but is usually not desirable.
45 Later in this chapter we will see how to deal with this issue.
46 </para>
48 <para>
49 Each column has a data type. The data type constrains the set of
50 possible values that can be assigned to a column and assigns
51 semantics to the data stored in the column so that it can be used
52 for computations. For instance, a column declared to be of a
53 numerical type will not accept arbitrary text strings, and the data
54 stored in such a column can be used for mathematical computations.
55 By contrast, a column declared to be of a character string type
56 will accept almost any kind of data but it does not lend itself to
57 mathematical calculations, although other operations such as string
58 concatenation are available.
59 </para>
61 <para>
62 <productname>PostgreSQL</productname> includes a sizable set of
63 built-in data types that fit many applications. Users can also
64 define their own data types. Most built-in data types have obvious
65 names and semantics, so we defer a detailed explanation to <xref
66 linkend="datatype">. Some of the frequently used data types are
67 <type>integer</type> for whole numbers, <type>numeric</type> for
68 possibly fractional numbers, <type>text</type> for character
69 strings, <type>date</type> for dates, <type>time</type> for
70 time-of-day values, and <type>timestamp</type> for values
71 containing both date and time.
72 </para>
74 <indexterm>
75 <primary>table</primary>
76 <secondary>creating</secondary>
77 </indexterm>
79 <para>
80 To create a table, you use the aptly named <xref
81 linkend="sql-createtable" endterm="sql-createtable-title"> command.
82 In this command you specify at least a name for the new table, the
83 names of the columns and the data type of each column. For
84 example:
85 <programlisting>
86 CREATE TABLE my_first_table (
87 first_column text,
88 second_column integer
90 </programlisting>
91 This creates a table named <literal>my_first_table</literal> with
92 two columns. The first column is named
93 <literal>first_column</literal> and has a data type of
94 <type>text</type>; the second column has the name
95 <literal>second_column</literal> and the type <type>integer</type>.
96 The table and column names follow the identifier syntax explained
97 in <xref linkend="sql-syntax-identifiers">. The type names are
98 usually also identifiers, but there are some exceptions. Note that the
99 column list is comma-separated and surrounded by parentheses.
100 </para>
102 <para>
103 Of course, the previous example was heavily contrived. Normally,
104 you would give names to your tables and columns that convey what
105 kind of data they store. So let's look at a more realistic
106 example:
107 <programlisting>
108 CREATE TABLE products (
109 product_no integer,
110 name text,
111 price numeric
113 </programlisting>
114 (The <type>numeric</type> type can store fractional components, as
115 would be typical of monetary amounts.)
116 </para>
118 <tip>
119 <para>
120 When you create many interrelated tables it is wise to choose a
121 consistent naming pattern for the tables and columns. For
122 instance, there is a choice of using singular or plural nouns for
123 table names, both of which are favored by some theorist or other.
124 </para>
125 </tip>
127 <para>
128 There is a limit on how many columns a table can contain.
129 Depending on the column types, it is between 250 and 1600.
130 However, defining a table with anywhere near this many columns is
131 highly unusual and often a questionable design.
132 </para>
134 <indexterm>
135 <primary>table</primary>
136 <secondary>removing</secondary>
137 </indexterm>
139 <para>
140 If you no longer need a table, you can remove it using the <xref
141 linkend="sql-droptable" endterm="sql-droptable-title"> command.
142 For example:
143 <programlisting>
144 DROP TABLE my_first_table;
145 DROP TABLE products;
146 </programlisting>
147 Attempting to drop a table that does not exist is an error.
148 Nevertheless, it is common in SQL script files to unconditionally
149 try to drop each table before creating it, ignoring any error
150 messages, so that the script works whether or not the table exists.
151 (If you like, you can use the <literal>DROP TABLE IF EXISTS</> variant
152 to avoid the error messages, but this is not standard SQL.)
153 </para>
155 <para>
156 If you need to modify a table that already exists look into <xref
157 linkend="ddl-alter"> later in this chapter.
158 </para>
160 <para>
161 With the tools discussed so far you can create fully functional
162 tables. The remainder of this chapter is concerned with adding
163 features to the table definition to ensure data integrity,
164 security, or convenience. If you are eager to fill your tables with
165 data now you can skip ahead to <xref linkend="dml"> and read the
166 rest of this chapter later.
167 </para>
168 </sect1>
170 <sect1 id="ddl-default">
171 <title>Default Values</title>
173 <indexterm zone="ddl-default">
174 <primary>default value</primary>
175 </indexterm>
177 <para>
178 A column can be assigned a default value. When a new row is
179 created and no values are specified for some of the columns, those
180 columns will be filled with their respective default values. A
181 data manipulation command can also request explicitly that a column
182 be set to its default value, without having to know what that value is.
183 (Details about data manipulation commands are in <xref linkend="dml">.)
184 </para>
186 <para>
187 <indexterm><primary>null value</primary><secondary>default value</secondary></indexterm>
188 If no default value is declared explicitly, the default value is the
189 null value. This usually makes sense because a null value can
190 be considered to represent unknown data.
191 </para>
193 <para>
194 In a table definition, default values are listed after the column
195 data type. For example:
196 <programlisting>
197 CREATE TABLE products (
198 product_no integer,
199 name text,
200 price numeric <emphasis>DEFAULT 9.99</emphasis>
202 </programlisting>
203 </para>
205 <para>
206 The default value can be an expression, which will be
207 evaluated whenever the default value is inserted
208 (<emphasis>not</emphasis> when the table is created). A common example
209 is that a <type>timestamp</type> column can have a default of <literal>now()</>,
210 so that it gets set to the time of row insertion. Another common
211 example is generating a <quote>serial number</> for each row.
212 In <productname>PostgreSQL</productname> this is typically done by
213 something like:
214 <programlisting>
215 CREATE TABLE products (
216 product_no integer <emphasis>DEFAULT nextval('products_product_no_seq')</emphasis>,
219 </programlisting>
220 where the <literal>nextval()</> function supplies successive values
221 from a <firstterm>sequence object</> (see <xref
222 linkend="functions-sequence">). This arrangement is sufficiently common
223 that there's a special shorthand for it:
224 <programlisting>
225 CREATE TABLE products (
226 product_no <emphasis>SERIAL</emphasis>,
229 </programlisting>
230 The <literal>SERIAL</> shorthand is discussed further in <xref
231 linkend="datatype-serial">.
232 </para>
233 </sect1>
235 <sect1 id="ddl-constraints">
236 <title>Constraints</title>
238 <indexterm zone="ddl-constraints">
239 <primary>constraint</primary>
240 </indexterm>
242 <para>
243 Data types are a way to limit the kind of data that can be stored
244 in a table. For many applications, however, the constraint they
245 provide is too coarse. For example, a column containing a product
246 price should probably only accept positive values. But there is no
247 standard data type that accepts only positive numbers. Another issue is
248 that you might want to constrain column data with respect to other
249 columns or rows. For example, in a table containing product
250 information, there should be only one row for each product number.
251 </para>
253 <para>
254 To that end, SQL allows you to define constraints on columns and
255 tables. Constraints give you as much control over the data in your
256 tables as you wish. If a user attempts to store data in a column
257 that would violate a constraint, an error is raised. This applies
258 even if the value came from the default value definition.
259 </para>
261 <sect2>
262 <title>Check Constraints</title>
264 <indexterm>
265 <primary>check constraint</primary>
266 </indexterm>
268 <indexterm>
269 <primary>constraint</primary>
270 <secondary>check</secondary>
271 </indexterm>
273 <para>
274 A check constraint is the most generic constraint type. It allows
275 you to specify that the value in a certain column must satisfy a
276 Boolean (truth-value) expression. For instance, to require positive
277 product prices, you could use:
278 <programlisting>
279 CREATE TABLE products (
280 product_no integer,
281 name text,
282 price numeric <emphasis>CHECK (price &gt; 0)</emphasis>
284 </programlisting>
285 </para>
287 <para>
288 As you see, the constraint definition comes after the data type,
289 just like default value definitions. Default values and
290 constraints can be listed in any order. A check constraint
291 consists of the key word <literal>CHECK</literal> followed by an
292 expression in parentheses. The check constraint expression should
293 involve the column thus constrained, otherwise the constraint
294 would not make too much sense.
295 </para>
297 <indexterm>
298 <primary>constraint</primary>
299 <secondary>name</secondary>
300 </indexterm>
302 <para>
303 You can also give the constraint a separate name. This clarifies
304 error messages and allows you to refer to the constraint when you
305 need to change it. The syntax is:
306 <programlisting>
307 CREATE TABLE products (
308 product_no integer,
309 name text,
310 price numeric <emphasis>CONSTRAINT positive_price</emphasis> CHECK (price &gt; 0)
312 </programlisting>
313 So, to specify a named constraint, use the key word
314 <literal>CONSTRAINT</literal> followed by an identifier followed
315 by the constraint definition. (If you don't specify a constraint
316 name in this way, the system chooses a name for you.)
317 </para>
319 <para>
320 A check constraint can also refer to several columns. Say you
321 store a regular price and a discounted price, and you want to
322 ensure that the discounted price is lower than the regular price:
323 <programlisting>
324 CREATE TABLE products (
325 product_no integer,
326 name text,
327 price numeric CHECK (price &gt; 0),
328 discounted_price numeric CHECK (discounted_price &gt; 0),
329 <emphasis>CHECK (price &gt; discounted_price)</emphasis>
331 </programlisting>
332 </para>
334 <para>
335 The first two constraints should look familiar. The third one
336 uses a new syntax. It is not attached to a particular column,
337 instead it appears as a separate item in the comma-separated
338 column list. Column definitions and these constraint
339 definitions can be listed in mixed order.
340 </para>
342 <para>
343 We say that the first two constraints are column constraints, whereas the
344 third one is a table constraint because it is written separately
345 from any one column definition. Column constraints can also be
346 written as table constraints, while the reverse is not necessarily
347 possible, since a column constraint is supposed to refer to only the
348 column it is attached to. (<productname>PostgreSQL</productname> doesn't
349 enforce that rule, but you should follow it if you want your table
350 definitions to work with other database systems.) The above example could
351 also be written as:
352 <programlisting>
353 CREATE TABLE products (
354 product_no integer,
355 name text,
356 price numeric,
357 CHECK (price &gt; 0),
358 discounted_price numeric,
359 CHECK (discounted_price &gt; 0),
360 CHECK (price &gt; discounted_price)
362 </programlisting>
363 or even:
364 <programlisting>
365 CREATE TABLE products (
366 product_no integer,
367 name text,
368 price numeric CHECK (price &gt; 0),
369 discounted_price numeric,
370 CHECK (discounted_price &gt; 0 AND price &gt; discounted_price)
372 </programlisting>
373 It's a matter of taste.
374 </para>
376 <para>
377 Names can be assigned to table constraints in just the same way as
378 for column constraints:
379 <programlisting>
380 CREATE TABLE products (
381 product_no integer,
382 name text,
383 price numeric,
384 CHECK (price &gt; 0),
385 discounted_price numeric,
386 CHECK (discounted_price &gt; 0),
387 <emphasis>CONSTRAINT valid_discount</> CHECK (price &gt; discounted_price)
389 </programlisting>
390 </para>
392 <indexterm>
393 <primary>null value</primary>
394 <secondary sortas="check constraints">with check constraints</secondary>
395 </indexterm>
397 <para>
398 It should be noted that a check constraint is satisfied if the
399 check expression evaluates to true or the null value. Since most
400 expressions will evaluate to the null value if any operand is null,
401 they will not prevent null values in the constrained columns. To
402 ensure that a column does not contain null values, the not-null
403 constraint described in the next section can be used.
404 </para>
405 </sect2>
407 <sect2>
408 <title>Not-Null Constraints</title>
410 <indexterm>
411 <primary>not-null constraint</primary>
412 </indexterm>
414 <indexterm>
415 <primary>constraint</primary>
416 <secondary>NOT NULL</secondary>
417 </indexterm>
419 <para>
420 A not-null constraint simply specifies that a column must not
421 assume the null value. A syntax example:
422 <programlisting>
423 CREATE TABLE products (
424 product_no integer <emphasis>NOT NULL</emphasis>,
425 name text <emphasis>NOT NULL</emphasis>,
426 price numeric
428 </programlisting>
429 </para>
431 <para>
432 A not-null constraint is always written as a column constraint. A
433 not-null constraint is functionally equivalent to creating a check
434 constraint <literal>CHECK (<replaceable>column_name</replaceable>
435 IS NOT NULL)</literal>, but in
436 <productname>PostgreSQL</productname> creating an explicit
437 not-null constraint is more efficient. The drawback is that you
438 cannot give explicit names to not-null constraints created this
439 way.
440 </para>
442 <para>
443 Of course, a column can have more than one constraint. Just write
444 the constraints one after another:
445 <programlisting>
446 CREATE TABLE products (
447 product_no integer NOT NULL,
448 name text NOT NULL,
449 price numeric NOT NULL CHECK (price &gt; 0)
451 </programlisting>
452 The order doesn't matter. It does not necessarily determine in which
453 order the constraints are checked.
454 </para>
456 <para>
457 The <literal>NOT NULL</literal> constraint has an inverse: the
458 <literal>NULL</literal> constraint. This does not mean that the
459 column must be null, which would surely be useless. Instead, this
460 simply selects the default behavior that the column might be null.
461 The <literal>NULL</literal> constraint is not present in the SQL
462 standard and should not be used in portable applications. (It was
463 only added to <productname>PostgreSQL</productname> to be
464 compatible with some other database systems.) Some users, however,
465 like it because it makes it easy to toggle the constraint in a
466 script file. For example, you could start with:
467 <programlisting>
468 CREATE TABLE products (
469 product_no integer NULL,
470 name text NULL,
471 price numeric NULL
473 </programlisting>
474 and then insert the <literal>NOT</literal> key word where desired.
475 </para>
477 <tip>
478 <para>
479 In most database designs the majority of columns should be marked
480 not null.
481 </para>
482 </tip>
483 </sect2>
485 <sect2>
486 <title>Unique Constraints</title>
488 <indexterm>
489 <primary>unique constraint</primary>
490 </indexterm>
492 <indexterm>
493 <primary>constraint</primary>
494 <secondary>unique</secondary>
495 </indexterm>
497 <para>
498 Unique constraints ensure that the data contained in a column or a
499 group of columns is unique with respect to all the rows in the
500 table. The syntax is:
501 <programlisting>
502 CREATE TABLE products (
503 product_no integer <emphasis>UNIQUE</emphasis>,
504 name text,
505 price numeric
507 </programlisting>
508 when written as a column constraint, and:
509 <programlisting>
510 CREATE TABLE products (
511 product_no integer,
512 name text,
513 price numeric,
514 <emphasis>UNIQUE (product_no)</emphasis>
516 </programlisting>
517 when written as a table constraint.
518 </para>
520 <para>
521 If a unique constraint refers to a group of columns, the columns
522 are listed separated by commas:
523 <programlisting>
524 CREATE TABLE example (
525 a integer,
526 b integer,
527 c integer,
528 <emphasis>UNIQUE (a, c)</emphasis>
530 </programlisting>
531 This specifies that the combination of values in the indicated columns
532 is unique across the whole table, though any one of the columns
533 need not be (and ordinarily isn't) unique.
534 </para>
536 <para>
537 You can assign your own name for a unique constraint, in the usual way:
538 <programlisting>
539 CREATE TABLE products (
540 product_no integer <emphasis>CONSTRAINT must_be_different</emphasis> UNIQUE,
541 name text,
542 price numeric
544 </programlisting>
545 </para>
547 <indexterm>
548 <primary>null value</primary>
549 <secondary sortas="unique constraints">with unique constraints</secondary>
550 </indexterm>
552 <para>
553 In general, a unique constraint is violated when there are two or
554 more rows in the table where the values of all of the
555 columns included in the constraint are equal.
556 However, two null values are not considered equal in this
557 comparison. That means even in the presence of a
558 unique constraint it is possible to store duplicate
559 rows that contain a null value in at least one of the constrained
560 columns. This behavior conforms to the SQL standard, but we have
561 heard that other SQL databases might not follow this rule. So be
562 careful when developing applications that are intended to be
563 portable.
564 </para>
565 </sect2>
567 <sect2>
568 <title>Primary Keys</title>
570 <indexterm>
571 <primary>primary key</primary>
572 </indexterm>
574 <indexterm>
575 <primary>constraint</primary>
576 <secondary>primary key</secondary>
577 </indexterm>
579 <para>
580 Technically, a primary key constraint is simply a combination of a
581 unique constraint and a not-null constraint. So, the following
582 two table definitions accept the same data:
583 <programlisting>
584 CREATE TABLE products (
585 product_no integer UNIQUE NOT NULL,
586 name text,
587 price numeric
589 </programlisting>
591 <programlisting>
592 CREATE TABLE products (
593 product_no integer <emphasis>PRIMARY KEY</emphasis>,
594 name text,
595 price numeric
597 </programlisting>
598 </para>
600 <para>
601 Primary keys can also constrain more than one column; the syntax
602 is similar to unique constraints:
603 <programlisting>
604 CREATE TABLE example (
605 a integer,
606 b integer,
607 c integer,
608 <emphasis>PRIMARY KEY (a, c)</emphasis>
610 </programlisting>
611 </para>
613 <para>
614 A primary key indicates that a column or group of columns can be
615 used as a unique identifier for rows in the table. (This is a
616 direct consequence of the definition of a primary key. Note that
617 a unique constraint does not, by itself, provide a unique identifier
618 because it does not exclude null values.) This is useful both for
619 documentation purposes and for client applications. For example,
620 a GUI application that allows modifying row values probably needs
621 to know the primary key of a table to be able to identify rows
622 uniquely.
623 </para>
625 <para>
626 A table can have at most one primary key. (There can be any number
627 of unique and not-null constraints, which are functionally the same
628 thing, but only one can be identified as the primary key.)
629 Relational database theory
630 dictates that every table must have a primary key. This rule is
631 not enforced by <productname>PostgreSQL</productname>, but it is
632 usually best to follow it.
633 </para>
634 </sect2>
636 <sect2 id="ddl-constraints-fk">
637 <title>Foreign Keys</title>
639 <indexterm>
640 <primary>foreign key</primary>
641 </indexterm>
643 <indexterm>
644 <primary>constraint</primary>
645 <secondary>foreign key</secondary>
646 </indexterm>
648 <indexterm>
649 <primary>referential integrity</primary>
650 </indexterm>
652 <para>
653 A foreign key constraint specifies that the values in a column (or
654 a group of columns) must match the values appearing in some row
655 of another table.
656 We say this maintains the <firstterm>referential
657 integrity</firstterm> between two related tables.
658 </para>
660 <para>
661 Say you have the product table that we have used several times already:
662 <programlisting>
663 CREATE TABLE products (
664 product_no integer PRIMARY KEY,
665 name text,
666 price numeric
668 </programlisting>
669 Let's also assume you have a table storing orders of those
670 products. We want to ensure that the orders table only contains
671 orders of products that actually exist. So we define a foreign
672 key constraint in the orders table that references the products
673 table:
674 <programlisting>
675 CREATE TABLE orders (
676 order_id integer PRIMARY KEY,
677 product_no integer <emphasis>REFERENCES products (product_no)</emphasis>,
678 quantity integer
680 </programlisting>
681 Now it is impossible to create orders with
682 <structfield>product_no</structfield> entries that do not appear in the
683 products table.
684 </para>
686 <para>
687 We say that in this situation the orders table is the
688 <firstterm>referencing</firstterm> table and the products table is
689 the <firstterm>referenced</firstterm> table. Similarly, there are
690 referencing and referenced columns.
691 </para>
693 <para>
694 You can also shorten the above command to:
695 <programlisting>
696 CREATE TABLE orders (
697 order_id integer PRIMARY KEY,
698 product_no integer <emphasis>REFERENCES products</emphasis>,
699 quantity integer
701 </programlisting>
702 because in absence of a column list the primary key of the
703 referenced table is used as the referenced column(s).
704 </para>
706 <para>
707 A foreign key can also constrain and reference a group of columns.
708 As usual, it then needs to be written in table constraint form.
709 Here is a contrived syntax example:
710 <programlisting>
711 CREATE TABLE t1 (
712 a integer PRIMARY KEY,
713 b integer,
714 c integer,
715 <emphasis>FOREIGN KEY (b, c) REFERENCES other_table (c1, c2)</emphasis>
717 </programlisting>
718 Of course, the number and type of the constrained columns need to
719 match the number and type of the referenced columns.
720 </para>
722 <para>
723 You can assign your own name for a foreign key constraint,
724 in the usual way.
725 </para>
727 <para>
728 A table can contain more than one foreign key constraint. This is
729 used to implement many-to-many relationships between tables. Say
730 you have tables about products and orders, but now you want to
731 allow one order to contain possibly many products (which the
732 structure above did not allow). You could use this table structure:
733 <programlisting>
734 CREATE TABLE products (
735 product_no integer PRIMARY KEY,
736 name text,
737 price numeric
740 CREATE TABLE orders (
741 order_id integer PRIMARY KEY,
742 shipping_address text,
746 CREATE TABLE order_items (
747 product_no integer REFERENCES products,
748 order_id integer REFERENCES orders,
749 quantity integer,
750 PRIMARY KEY (product_no, order_id)
752 </programlisting>
753 Notice that the primary key overlaps with the foreign keys in
754 the last table.
755 </para>
757 <indexterm>
758 <primary>CASCADE</primary>
759 <secondary>foreign key action</secondary>
760 </indexterm>
762 <indexterm>
763 <primary>RESTRICT</primary>
764 <secondary>foreign key action</secondary>
765 </indexterm>
767 <para>
768 We know that the foreign keys disallow creation of orders that
769 do not relate to any products. But what if a product is removed
770 after an order is created that references it? SQL allows you to
771 handle that as well. Intuitively, we have a few options:
772 <itemizedlist spacing="compact">
773 <listitem><para>Disallow deleting a referenced product</para></listitem>
774 <listitem><para>Delete the orders as well</para></listitem>
775 <listitem><para>Something else?</para></listitem>
776 </itemizedlist>
777 </para>
779 <para>
780 To illustrate this, let's implement the following policy on the
781 many-to-many relationship example above: when someone wants to
782 remove a product that is still referenced by an order (via
783 <literal>order_items</literal>), we disallow it. If someone
784 removes an order, the order items are removed as well:
785 <programlisting>
786 CREATE TABLE products (
787 product_no integer PRIMARY KEY,
788 name text,
789 price numeric
792 CREATE TABLE orders (
793 order_id integer PRIMARY KEY,
794 shipping_address text,
798 CREATE TABLE order_items (
799 product_no integer REFERENCES products <emphasis>ON DELETE RESTRICT</emphasis>,
800 order_id integer REFERENCES orders <emphasis>ON DELETE CASCADE</emphasis>,
801 quantity integer,
802 PRIMARY KEY (product_no, order_id)
804 </programlisting>
805 </para>
807 <para>
808 Restricting and cascading deletes are the two most common options.
809 <literal>RESTRICT</literal> prevents deletion of a
810 referenced row. <literal>NO ACTION</literal> means that if any
811 referencing rows still exist when the constraint is checked, an error
812 is raised; this is the default behavior if you do not specify anything.
813 (The essential difference between these two choices is that
814 <literal>NO ACTION</literal> allows the check to be deferred until
815 later in the transaction, whereas <literal>RESTRICT</literal> does not.)
816 <literal>CASCADE</> specifies that when a referenced row is deleted,
817 row(s) referencing it should be automatically deleted as well.
818 There are two other options:
819 <literal>SET NULL</literal> and <literal>SET DEFAULT</literal>.
820 These cause the referencing columns to be set to nulls or default
821 values, respectively, when the referenced row is deleted.
822 Note that these do not excuse you from observing any constraints.
823 For example, if an action specifies <literal>SET DEFAULT</literal>
824 but the default value would not satisfy the foreign key, the
825 operation will fail.
826 </para>
828 <para>
829 Analogous to <literal>ON DELETE</literal> there is also
830 <literal>ON UPDATE</literal> which is invoked when a referenced
831 column is changed (updated). The possible actions are the same.
832 </para>
834 <para>
835 More information about updating and deleting data is in <xref
836 linkend="dml">.
837 </para>
839 <para>
840 Finally, we should mention that a foreign key must reference
841 columns that either are a primary key or form a unique constraint.
842 If the foreign key references a unique constraint, there are some
843 additional possibilities regarding how null values are matched.
844 These are explained in the reference documentation for
845 <xref linkend="sql-createtable" endterm="sql-createtable-title">.
846 </para>
847 </sect2>
848 </sect1>
850 <sect1 id="ddl-system-columns">
851 <title>System Columns</title>
853 <para>
854 Every table has several <firstterm>system columns</> that are
855 implicitly defined by the system. Therefore, these names cannot be
856 used as names of user-defined columns. (Note that these
857 restrictions are separate from whether the name is a key word or
858 not; quoting a name will not allow you to escape these
859 restrictions.) You do not really need to be concerned about these
860 columns, just know they exist.
861 </para>
863 <indexterm>
864 <primary>column</primary>
865 <secondary>system column</secondary>
866 </indexterm>
868 <variablelist>
869 <varlistentry>
870 <term><structfield>oid</></term>
871 <listitem>
872 <para>
873 <indexterm>
874 <primary>OID</primary>
875 <secondary>column</secondary>
876 </indexterm>
877 The object identifier (object ID) of a row. This column is only
878 present if the table was created using <literal>WITH
879 OIDS</literal>, or if the <xref linkend="guc-default-with-oids">
880 configuration variable was set at the time. This column is of type
881 <type>oid</type> (same name as the column); see <xref
882 linkend="datatype-oid"> for more information about the type.
883 </para>
884 </listitem>
885 </varlistentry>
887 <varlistentry>
888 <term><structfield>tableoid</></term>
889 <listitem>
890 <indexterm>
891 <primary>tableoid</primary>
892 </indexterm>
894 <para>
895 The OID of the table containing this row. This column is
896 particularly handy for queries that select from inheritance
897 hierarchies (see <xref linkend="ddl-inherit">), since without it,
898 it's difficult to tell which individual table a row came from. The
899 <structfield>tableoid</structfield> can be joined against the
900 <structfield>oid</structfield> column of
901 <structname>pg_class</structname> to obtain the table name.
902 </para>
903 </listitem>
904 </varlistentry>
906 <varlistentry>
907 <term><structfield>xmin</></term>
908 <listitem>
909 <indexterm>
910 <primary>xmin</primary>
911 </indexterm>
913 <para>
914 The identity (transaction ID) of the inserting transaction for
915 this row version. (A row version is an individual state of a
916 row; each update of a row creates a new row version for the same
917 logical row.)
918 </para>
919 </listitem>
920 </varlistentry>
922 <varlistentry>
923 <term><structfield>cmin</></term>
924 <listitem>
925 <indexterm>
926 <primary>cmin</primary>
927 </indexterm>
929 <para>
930 The command identifier (starting at zero) within the inserting
931 transaction.
932 </para>
933 </listitem>
934 </varlistentry>
936 <varlistentry>
937 <term><structfield>xmax</></term>
938 <listitem>
939 <indexterm>
940 <primary>xmax</primary>
941 </indexterm>
943 <para>
944 The identity (transaction ID) of the deleting transaction, or
945 zero for an undeleted row version. It is possible for this column to
946 be nonzero in a visible row version. That usually indicates that the
947 deleting transaction hasn't committed yet, or that an attempted
948 deletion was rolled back.
949 </para>
950 </listitem>
951 </varlistentry>
953 <varlistentry>
954 <term><structfield>cmax</></term>
955 <listitem>
956 <indexterm>
957 <primary>cmax</primary>
958 </indexterm>
960 <para>
961 The command identifier within the deleting transaction, or zero.
962 </para>
963 </listitem>
964 </varlistentry>
966 <varlistentry>
967 <term><structfield>ctid</></term>
968 <listitem>
969 <indexterm>
970 <primary>ctid</primary>
971 </indexterm>
973 <para>
974 The physical location of the row version within its table. Note that
975 although the <structfield>ctid</structfield> can be used to
976 locate the row version very quickly, a row's
977 <structfield>ctid</structfield> will change if it is
978 updated or moved by <command>VACUUM FULL</>. Therefore
979 <structfield>ctid</structfield> is useless as a long-term row
980 identifier. The OID, or even better a user-defined serial
981 number, should be used to identify logical rows.
982 </para>
983 </listitem>
984 </varlistentry>
985 </variablelist>
987 <para>
988 OIDs are 32-bit quantities and are assigned from a single
989 cluster-wide counter. In a large or long-lived database, it is
990 possible for the counter to wrap around. Hence, it is bad
991 practice to assume that OIDs are unique, unless you take steps to
992 ensure that this is the case. If you need to identify the rows in
993 a table, using a sequence generator is strongly recommended.
994 However, OIDs can be used as well, provided that a few additional
995 precautions are taken:
997 <itemizedlist>
998 <listitem>
999 <para>
1000 A unique constraint should be created on the OID column of each
1001 table for which the OID will be used to identify rows. When such
1002 a unique constraint (or unique index) exists, the system takes
1003 care not to generate an OID matching an already-existing row.
1004 (Of course, this is only possible if the table contains fewer
1005 than 2<superscript>32</> (4 billion) rows, and in practice the
1006 table size had better be much less than that, or performance
1007 might suffer.)
1008 </para>
1009 </listitem>
1010 <listitem>
1011 <para>
1012 OIDs should never be assumed to be unique across tables; use
1013 the combination of <structfield>tableoid</> and row OID if you
1014 need a database-wide identifier.
1015 </para>
1016 </listitem>
1017 <listitem>
1018 <para>
1019 Of course, the tables in question must be created <literal>WITH
1020 OIDS</literal>. As of <productname>PostgreSQL</productname> 8.1,
1021 <literal>WITHOUT OIDS</> is the default.
1022 </para>
1023 </listitem>
1024 </itemizedlist>
1025 </para>
1027 <para>
1028 Transaction identifiers are also 32-bit quantities. In a
1029 long-lived database it is possible for transaction IDs to wrap
1030 around. This is not a fatal problem given appropriate maintenance
1031 procedures; see <xref linkend="maintenance"> for details. It is
1032 unwise, however, to depend on the uniqueness of transaction IDs
1033 over the long term (more than one billion transactions).
1034 </para>
1036 <para>
1037 Command identifiers are also 32-bit quantities. This creates a hard limit
1038 of 2<superscript>32</> (4 billion) <acronym>SQL</acronym> commands
1039 within a single transaction. In practice this limit is not a
1040 problem &mdash; note that the limit is on number of
1041 <acronym>SQL</acronym> commands, not number of rows processed.
1042 Also, as of <productname>PostgreSQL</productname> 8.3, only commands
1043 that actually modify the database contents will consume a command
1044 identifier.
1045 </para>
1046 </sect1>
1048 <sect1 id="ddl-alter">
1049 <title>Modifying Tables</title>
1051 <indexterm zone="ddl-alter">
1052 <primary>table</primary>
1053 <secondary>modifying</secondary>
1054 </indexterm>
1056 <para>
1057 When you create a table and you realize that you made a mistake, or
1058 the requirements of the application change, then you can drop the
1059 table and create it again. But this is not a convenient option if
1060 the table is already filled with data, or if the table is
1061 referenced by other database objects (for instance a foreign key
1062 constraint). Therefore <productname>PostgreSQL</productname>
1063 provides a family of commands to make modifications to existing
1064 tables. Note that this is conceptually distinct from altering
1065 the data contained in the table: here we are interested in altering
1066 the definition, or structure, of the table.
1067 </para>
1069 <para>
1070 You can
1071 <itemizedlist spacing="compact">
1072 <listitem>
1073 <para>Add columns,</para>
1074 </listitem>
1075 <listitem>
1076 <para>Remove columns,</para>
1077 </listitem>
1078 <listitem>
1079 <para>Add constraints,</para>
1080 </listitem>
1081 <listitem>
1082 <para>Remove constraints,</para>
1083 </listitem>
1084 <listitem>
1085 <para>Change default values,</para>
1086 </listitem>
1087 <listitem>
1088 <para>Change column data types,</para>
1089 </listitem>
1090 <listitem>
1091 <para>Rename columns,</para>
1092 </listitem>
1093 <listitem>
1094 <para>Rename tables.</para>
1095 </listitem>
1096 </itemizedlist>
1098 All these actions are performed using the
1099 <xref linkend="sql-altertable" endterm="sql-altertable-title">
1100 command, whose reference page contains details beyond those given
1101 here.
1102 </para>
1104 <sect2>
1105 <title>Adding a Column</title>
1107 <indexterm>
1108 <primary>column</primary>
1109 <secondary>adding</secondary>
1110 </indexterm>
1112 <para>
1113 To add a column, use a command like this:
1114 <programlisting>
1115 ALTER TABLE products ADD COLUMN description text;
1116 </programlisting>
1117 The new column is initially filled with whatever default
1118 value is given (null if you don't specify a <literal>DEFAULT</> clause).
1119 </para>
1121 <para>
1122 You can also define constraints on the column at the same time,
1123 using the usual syntax:
1124 <programlisting>
1125 ALTER TABLE products ADD COLUMN description text CHECK (description &lt;&gt; '');
1126 </programlisting>
1127 In fact all the options that can be applied to a column description
1128 in <command>CREATE TABLE</> can be used here. Keep in mind however
1129 that the default value must satisfy the given constraints, or the
1130 <literal>ADD</> will fail. Alternatively, you can add
1131 constraints later (see below) after you've filled in the new column
1132 correctly.
1133 </para>
1135 <tip>
1136 <para>
1137 Adding a column with a default requires updating each row of the
1138 table (to store the new column value). However, if no default is
1139 specified, <productname>PostgreSQL</productname> is able to avoid
1140 the physical update. So if you intend to fill the column with
1141 mostly nondefault values, it's best to add the column with no default,
1142 insert the correct values using <command>UPDATE</>, and then add any
1143 desired default as described below.
1144 </para>
1145 </tip>
1146 </sect2>
1148 <sect2>
1149 <title>Removing a Column</title>
1151 <indexterm>
1152 <primary>column</primary>
1153 <secondary>removing</secondary>
1154 </indexterm>
1156 <para>
1157 To remove a column, use a command like this:
1158 <programlisting>
1159 ALTER TABLE products DROP COLUMN description;
1160 </programlisting>
1161 Whatever data was in the column disappears. Table constraints involving
1162 the column are dropped, too. However, if the column is referenced by a
1163 foreign key constraint of another table,
1164 <productname>PostgreSQL</productname> will not silently drop that
1165 constraint. You can authorize dropping everything that depends on
1166 the column by adding <literal>CASCADE</>:
1167 <programlisting>
1168 ALTER TABLE products DROP COLUMN description CASCADE;
1169 </programlisting>
1170 See <xref linkend="ddl-depend"> for a description of the general
1171 mechanism behind this.
1172 </para>
1173 </sect2>
1175 <sect2>
1176 <title>Adding a Constraint</title>
1178 <indexterm>
1179 <primary>constraint</primary>
1180 <secondary>adding</secondary>
1181 </indexterm>
1183 <para>
1184 To add a constraint, the table constraint syntax is used. For example:
1185 <programlisting>
1186 ALTER TABLE products ADD CHECK (name &lt;&gt; '');
1187 ALTER TABLE products ADD CONSTRAINT some_name UNIQUE (product_no);
1188 ALTER TABLE products ADD FOREIGN KEY (product_group_id) REFERENCES product_groups;
1189 </programlisting>
1190 To add a not-null constraint, which cannot be written as a table
1191 constraint, use this syntax:
1192 <programlisting>
1193 ALTER TABLE products ALTER COLUMN product_no SET NOT NULL;
1194 </programlisting>
1195 </para>
1197 <para>
1198 The constraint will be checked immediately, so the table data must
1199 satisfy the constraint before it can be added.
1200 </para>
1201 </sect2>
1203 <sect2>
1204 <title>Removing a Constraint</title>
1206 <indexterm>
1207 <primary>constraint</primary>
1208 <secondary>removing</secondary>
1209 </indexterm>
1211 <para>
1212 To remove a constraint you need to know its name. If you gave it
1213 a name then that's easy. Otherwise the system assigned a
1214 generated name, which you need to find out. The
1215 <application>psql</application> command <literal>\d
1216 <replaceable>tablename</replaceable></literal> can be helpful
1217 here; other interfaces might also provide a way to inspect table
1218 details. Then the command is:
1219 <programlisting>
1220 ALTER TABLE products DROP CONSTRAINT some_name;
1221 </programlisting>
1222 (If you are dealing with a generated constraint name like <literal>$2</>,
1223 don't forget that you'll need to double-quote it to make it a valid
1224 identifier.)
1225 </para>
1227 <para>
1228 As with dropping a column, you need to add <literal>CASCADE</> if you
1229 want to drop a constraint that something else depends on. An example
1230 is that a foreign key constraint depends on a unique or primary key
1231 constraint on the referenced column(s).
1232 </para>
1234 <para>
1235 This works the same for all constraint types except not-null
1236 constraints. To drop a not null constraint use:
1237 <programlisting>
1238 ALTER TABLE products ALTER COLUMN product_no DROP NOT NULL;
1239 </programlisting>
1240 (Recall that not-null constraints do not have names.)
1241 </para>
1242 </sect2>
1244 <sect2>
1245 <title>Changing a Column's Default Value</title>
1247 <indexterm>
1248 <primary>default value</primary>
1249 <secondary>changing</secondary>
1250 </indexterm>
1252 <para>
1253 To set a new default for a column, use a command like this:
1254 <programlisting>
1255 ALTER TABLE products ALTER COLUMN price SET DEFAULT 7.77;
1256 </programlisting>
1257 Note that this doesn't affect any existing rows in the table, it
1258 just changes the default for future <command>INSERT</> commands.
1259 </para>
1261 <para>
1262 To remove any default value, use:
1263 <programlisting>
1264 ALTER TABLE products ALTER COLUMN price DROP DEFAULT;
1265 </programlisting>
1266 This is effectively the same as setting the default to null.
1267 As a consequence, it is not an error
1268 to drop a default where one hadn't been defined, because the
1269 default is implicitly the null value.
1270 </para>
1271 </sect2>
1273 <sect2>
1274 <title>Changing a Column's Data Type</title>
1276 <indexterm>
1277 <primary>column data type</primary>
1278 <secondary>changing</secondary>
1279 </indexterm>
1281 <para>
1282 To convert a column to a different data type, use a command like this:
1283 <programlisting>
1284 ALTER TABLE products ALTER COLUMN price TYPE numeric(10,2);
1285 </programlisting>
1286 This will succeed only if each existing entry in the column can be
1287 converted to the new type by an implicit cast. If a more complex
1288 conversion is needed, you can add a <literal>USING</> clause that
1289 specifies how to compute the new values from the old.
1290 </para>
1292 <para>
1293 <productname>PostgreSQL</> will attempt to convert the column's
1294 default value (if any) to the new type, as well as any constraints
1295 that involve the column. But these conversions might fail, or might
1296 produce surprising results. It's often best to drop any constraints
1297 on the column before altering its type, and then add back suitably
1298 modified constraints afterwards.
1299 </para>
1300 </sect2>
1302 <sect2>
1303 <title>Renaming a Column</title>
1305 <indexterm>
1306 <primary>column</primary>
1307 <secondary>renaming</secondary>
1308 </indexterm>
1310 <para>
1311 To rename a column:
1312 <programlisting>
1313 ALTER TABLE products RENAME COLUMN product_no TO product_number;
1314 </programlisting>
1315 </para>
1316 </sect2>
1318 <sect2>
1319 <title>Renaming a Table</title>
1321 <indexterm>
1322 <primary>table</primary>
1323 <secondary>renaming</secondary>
1324 </indexterm>
1326 <para>
1327 To rename a table:
1328 <programlisting>
1329 ALTER TABLE products RENAME TO items;
1330 </programlisting>
1331 </para>
1332 </sect2>
1333 </sect1>
1335 <sect1 id="ddl-priv">
1336 <title>Privileges</title>
1338 <indexterm zone="ddl-priv">
1339 <primary>privilege</primary>
1340 </indexterm>
1342 <indexterm>
1343 <primary>permission</primary>
1344 <see>privilege</see>
1345 </indexterm>
1347 <para>
1348 When you create a database object, you become its owner. By
1349 default, only the owner of an object can do anything with the
1350 object. In order to allow other users to use it,
1351 <firstterm>privileges</firstterm> must be granted. (However,
1352 users that have the superuser attribute can always
1353 access any object.)
1354 </para>
1356 <para>
1357 There are several different privileges: <literal>SELECT</>,
1358 <literal>INSERT</>, <literal>UPDATE</>, <literal>DELETE</>,
1359 <literal>TRUNCATE</>, <literal>REFERENCES</>, <literal>TRIGGER</>,
1360 <literal>CREATE</>, <literal>CONNECT</>, <literal>TEMPORARY</>,
1361 <literal>EXECUTE</>, and <literal>USAGE</>.
1362 The privileges applicable to a particular
1363 object vary depending on the object's type (table, function, etc).
1364 For complete information on the different types of privileges
1365 supported by <productname>PostgreSQL</productname>, refer to the
1366 <xref linkend="sql-grant" endterm="sql-grant-title"> reference
1367 page. The following sections and chapters will also show you how
1368 those privileges are used.
1369 </para>
1371 <para>
1372 The right to modify or destroy an object is always the privilege of
1373 the owner only.
1374 </para>
1376 <note>
1377 <para>
1378 To change the owner of a table, index, sequence, or view, use the
1379 <xref linkend="sql-altertable" endterm="sql-altertable-title">
1380 command. There are corresponding <literal>ALTER</> commands for
1381 other object types.
1382 </para>
1383 </note>
1385 <para>
1386 To assign privileges, the <command>GRANT</command> command is
1387 used. For example, if <literal>joe</literal> is an existing user, and
1388 <literal>accounts</literal> is an existing table, the privilege to
1389 update the table can be granted with:
1390 <programlisting>
1391 GRANT UPDATE ON accounts TO joe;
1392 </programlisting>
1393 Writing <literal>ALL</literal> in place of a specific privilege grants all
1394 privileges that are relevant for the object type.
1395 </para>
1397 <para>
1398 The special <quote>user</quote> name <literal>PUBLIC</literal> can
1399 be used to grant a privilege to every user on the system. Also,
1400 <quote>group</> roles can be set up to help manage privileges when
1401 there are many users of a database &mdash; for details see
1402 <xref linkend="user-manag">.
1403 </para>
1405 <para>
1406 To revoke a privilege, use the fittingly named
1407 <command>REVOKE</command> command:
1408 <programlisting>
1409 REVOKE ALL ON accounts FROM PUBLIC;
1410 </programlisting>
1411 The special privileges of the object owner (i.e., the right to do
1412 <command>DROP</>, <command>GRANT</>, <command>REVOKE</>, etc.)
1413 are always implicit in being the owner,
1414 and cannot be granted or revoked. But the object owner can choose
1415 to revoke his own ordinary privileges, for example to make a
1416 table read-only for himself as well as others.
1417 </para>
1419 <para>
1420 Ordinarily, only the object's owner (or a superuser) can grant or
1421 revoke privileges on an object. However, it is possible to grant a
1422 privilege <quote>with grant option</>, which gives the recipient
1423 the right to grant it in turn to others. If the grant option is
1424 subsequently revoked then all who received the privilege from that
1425 recipient (directly or through a chain of grants) will lose the
1426 privilege. For details see the <xref linkend="sql-grant"
1427 endterm="sql-grant-title"> and <xref linkend="sql-revoke"
1428 endterm="sql-revoke-title"> reference pages.
1429 </para>
1430 </sect1>
1432 <sect1 id="ddl-schemas">
1433 <title>Schemas</title>
1435 <indexterm zone="ddl-schemas">
1436 <primary>schema</primary>
1437 </indexterm>
1439 <para>
1440 A <productname>PostgreSQL</productname> database cluster
1441 contains one or more named databases. Users and groups of users are
1442 shared across the entire cluster, but no other data is shared across
1443 databases. Any given client connection to the server can access
1444 only the data in a single database, the one specified in the connection
1445 request.
1446 </para>
1448 <note>
1449 <para>
1450 Users of a cluster do not necessarily have the privilege to access every
1451 database in the cluster. Sharing of user names means that there
1452 cannot be different users named, say, <literal>joe</> in two databases
1453 in the same cluster; but the system can be configured to allow
1454 <literal>joe</> access to only some of the databases.
1455 </para>
1456 </note>
1458 <para>
1459 A database contains one or more named <firstterm>schemas</>, which
1460 in turn contain tables. Schemas also contain other kinds of named
1461 objects, including data types, functions, and operators. The same
1462 object name can be used in different schemas without conflict; for
1463 example, both <literal>schema1</> and <literal>myschema</> can
1464 contain tables named <literal>mytable</>. Unlike databases,
1465 schemas are not rigidly separated: a user can access objects in any
1466 of the schemas in the database he is connected to, if he has
1467 privileges to do so.
1468 </para>
1470 <para>
1471 There are several reasons why one might want to use schemas:
1473 <itemizedlist>
1474 <listitem>
1475 <para>
1476 To allow many users to use one database without interfering with
1477 each other.
1478 </para>
1479 </listitem>
1481 <listitem>
1482 <para>
1483 To organize database objects into logical groups to make them
1484 more manageable.
1485 </para>
1486 </listitem>
1488 <listitem>
1489 <para>
1490 Third-party applications can be put into separate schemas so
1491 they cannot collide with the names of other objects.
1492 </para>
1493 </listitem>
1494 </itemizedlist>
1496 Schemas are analogous to directories at the operating system level,
1497 except that schemas cannot be nested.
1498 </para>
1500 <sect2 id="ddl-schemas-create">
1501 <title>Creating a Schema</title>
1503 <indexterm zone="ddl-schemas-create">
1504 <primary>schema</primary>
1505 <secondary>creating</secondary>
1506 </indexterm>
1508 <para>
1509 To create a schema, use the <xref linkend="sql-createschema"
1510 endterm="sql-createschema-title"> command. Give the schema a name
1511 of your choice. For example:
1512 <programlisting>
1513 CREATE SCHEMA myschema;
1514 </programlisting>
1515 </para>
1517 <indexterm>
1518 <primary>qualified name</primary>
1519 </indexterm>
1521 <indexterm>
1522 <primary>name</primary>
1523 <secondary>qualified</secondary>
1524 </indexterm>
1526 <para>
1527 To create or access objects in a schema, write a
1528 <firstterm>qualified name</> consisting of the schema name and
1529 table name separated by a dot:
1530 <synopsis>
1531 <replaceable>schema</><literal>.</><replaceable>table</>
1532 </synopsis>
1533 This works anywhere a table name is expected, including the table
1534 modification commands and the data access commands discussed in
1535 the following chapters.
1536 (For brevity we will speak of tables only, but the same ideas apply
1537 to other kinds of named objects, such as types and functions.)
1538 </para>
1540 <para>
1541 Actually, the even more general syntax
1542 <synopsis>
1543 <replaceable>database</><literal>.</><replaceable>schema</><literal>.</><replaceable>table</>
1544 </synopsis>
1545 can be used too, but at present this is just for <foreignphrase>pro
1546 forma</> compliance with the SQL standard. If you write a database name,
1547 it must be the same as the database you are connected to.
1548 </para>
1550 <para>
1551 So to create a table in the new schema, use:
1552 <programlisting>
1553 CREATE TABLE myschema.mytable (
1556 </programlisting>
1557 </para>
1559 <indexterm>
1560 <primary>schema</primary>
1561 <secondary>removing</secondary>
1562 </indexterm>
1564 <para>
1565 To drop a schema if it's empty (all objects in it have been
1566 dropped), use:
1567 <programlisting>
1568 DROP SCHEMA myschema;
1569 </programlisting>
1570 To drop a schema including all contained objects, use:
1571 <programlisting>
1572 DROP SCHEMA myschema CASCADE;
1573 </programlisting>
1574 See <xref linkend="ddl-depend"> for a description of the general
1575 mechanism behind this.
1576 </para>
1578 <para>
1579 Often you will want to create a schema owned by someone else
1580 (since this is one of the ways to restrict the activities of your
1581 users to well-defined namespaces). The syntax for that is:
1582 <programlisting>
1583 CREATE SCHEMA <replaceable>schemaname</replaceable> AUTHORIZATION <replaceable>username</replaceable>;
1584 </programlisting>
1585 You can even omit the schema name, in which case the schema name
1586 will be the same as the user name. See <xref
1587 linkend="ddl-schemas-patterns"> for how this can be useful.
1588 </para>
1590 <para>
1591 Schema names beginning with <literal>pg_</> are reserved for
1592 system purposes and cannot be created by users.
1593 </para>
1594 </sect2>
1596 <sect2 id="ddl-schemas-public">
1597 <title>The Public Schema</title>
1599 <indexterm zone="ddl-schemas-public">
1600 <primary>schema</primary>
1601 <secondary>public</secondary>
1602 </indexterm>
1604 <para>
1605 In the previous sections we created tables without specifying any
1606 schema names. By default, such tables (and other objects) are
1607 automatically put into a schema named <quote>public</quote>. Every new
1608 database contains such a schema. Thus, the following are equivalent:
1609 <programlisting>
1610 CREATE TABLE products ( ... );
1611 </programlisting>
1612 and:
1613 <programlisting>
1614 CREATE TABLE public.products ( ... );
1615 </programlisting>
1616 </para>
1617 </sect2>
1619 <sect2 id="ddl-schemas-path">
1620 <title>The Schema Search Path</title>
1622 <indexterm>
1623 <primary>search path</primary>
1624 </indexterm>
1626 <indexterm>
1627 <primary>unqualified name</primary>
1628 </indexterm>
1630 <indexterm>
1631 <primary>name</primary>
1632 <secondary>unqualified</secondary>
1633 </indexterm>
1635 <para>
1636 Qualified names are tedious to write, and it's often best not to
1637 wire a particular schema name into applications anyway. Therefore
1638 tables are often referred to by <firstterm>unqualified names</>,
1639 which consist of just the table name. The system determines which table
1640 is meant by following a <firstterm>search path</>, which is a list
1641 of schemas to look in. The first matching table in the search path
1642 is taken to be the one wanted. If there is no match in the search
1643 path, an error is reported, even if matching table names exist
1644 in other schemas in the database.
1645 </para>
1647 <indexterm>
1648 <primary>schema</primary>
1649 <secondary>current</secondary>
1650 </indexterm>
1652 <para>
1653 The first schema named in the search path is called the current schema.
1654 Aside from being the first schema searched, it is also the schema in
1655 which new tables will be created if the <command>CREATE TABLE</>
1656 command does not specify a schema name.
1657 </para>
1659 <indexterm>
1660 <primary>search_path</primary>
1661 </indexterm>
1663 <para>
1664 To show the current search path, use the following command:
1665 <programlisting>
1666 SHOW search_path;
1667 </programlisting>
1668 In the default setup this returns:
1669 <screen>
1670 search_path
1671 --------------
1672 "$user",public
1673 </screen>
1674 The first element specifies that a schema with the same name as
1675 the current user is to be searched. If no such schema exists,
1676 the entry is ignored. The second element refers to the
1677 public schema that we have seen already.
1678 </para>
1680 <para>
1681 The first schema in the search path that exists is the default
1682 location for creating new objects. That is the reason that by
1683 default objects are created in the public schema. When objects
1684 are referenced in any other context without schema qualification
1685 (table modification, data modification, or query commands) the
1686 search path is traversed until a matching object is found.
1687 Therefore, in the default configuration, any unqualified access
1688 again can only refer to the public schema.
1689 </para>
1691 <para>
1692 To put our new schema in the path, we use:
1693 <programlisting>
1694 SET search_path TO myschema,public;
1695 </programlisting>
1696 (We omit the <literal>$user</literal> here because we have no
1697 immediate need for it.) And then we can access the table without
1698 schema qualification:
1699 <programlisting>
1700 DROP TABLE mytable;
1701 </programlisting>
1702 Also, since <literal>myschema</literal> is the first element in
1703 the path, new objects would by default be created in it.
1704 </para>
1706 <para>
1707 We could also have written:
1708 <programlisting>
1709 SET search_path TO myschema;
1710 </programlisting>
1711 Then we no longer have access to the public schema without
1712 explicit qualification. There is nothing special about the public
1713 schema except that it exists by default. It can be dropped, too.
1714 </para>
1716 <para>
1717 See also <xref linkend="functions-info"> for other ways to manipulate
1718 the schema search path.
1719 </para>
1721 <para>
1722 The search path works in the same way for data type names, function names,
1723 and operator names as it does for table names. Data type and function
1724 names can be qualified in exactly the same way as table names. If you
1725 need to write a qualified operator name in an expression, there is a
1726 special provision: you must write
1727 <synopsis>
1728 <literal>OPERATOR(</><replaceable>schema</><literal>.</><replaceable>operator</><literal>)</>
1729 </synopsis>
1730 This is needed to avoid syntactic ambiguity. An example is:
1731 <programlisting>
1732 SELECT 3 OPERATOR(pg_catalog.+) 4;
1733 </programlisting>
1734 In practice one usually relies on the search path for operators,
1735 so as not to have to write anything so ugly as that.
1736 </para>
1737 </sect2>
1739 <sect2 id="ddl-schemas-priv">
1740 <title>Schemas and Privileges</title>
1742 <indexterm zone="ddl-schemas-priv">
1743 <primary>privilege</primary>
1744 <secondary sortas="schemas">for schemas</secondary>
1745 </indexterm>
1747 <para>
1748 By default, users cannot access any objects in schemas they do not
1749 own. To allow that, the owner of the schema needs to grant the
1750 <literal>USAGE</literal> privilege on the schema. To allow users
1751 to make use of the objects in the schema, additional privileges
1752 might need to be granted, as appropriate for the object.
1753 </para>
1755 <para>
1756 A user can also be allowed to create objects in someone else's
1757 schema. To allow that, the <literal>CREATE</literal> privilege on
1758 the schema needs to be granted. Note that by default, everyone
1759 has <literal>CREATE</literal> and <literal>USAGE</literal> privileges on
1760 the schema
1761 <literal>public</literal>. This allows all users that are able to
1762 connect to a given database to create objects in its
1763 <literal>public</literal> schema. If you do
1764 not want to allow that, you can revoke that privilege:
1765 <programlisting>
1766 REVOKE CREATE ON SCHEMA public FROM PUBLIC;
1767 </programlisting>
1768 (The first <quote>public</quote> is the schema, the second
1769 <quote>public</quote> means <quote>every user</quote>. In the
1770 first sense it is an identifier, in the second sense it is a
1771 key word, hence the different capitalization; recall the
1772 guidelines from <xref linkend="sql-syntax-identifiers">.)
1773 </para>
1774 </sect2>
1776 <sect2 id="ddl-schemas-catalog">
1777 <title>The System Catalog Schema</title>
1779 <indexterm zone="ddl-schemas-catalog">
1780 <primary>system catalog</primary>
1781 <secondary>schema</secondary>
1782 </indexterm>
1784 <para>
1785 In addition to <literal>public</> and user-created schemas, each
1786 database contains a <literal>pg_catalog</> schema, which contains
1787 the system tables and all the built-in data types, functions, and
1788 operators. <literal>pg_catalog</> is always effectively part of
1789 the search path. If it is not named explicitly in the path then
1790 it is implicitly searched <emphasis>before</> searching the path's
1791 schemas. This ensures that built-in names will always be
1792 findable. However, you can explicitly place
1793 <literal>pg_catalog</> at the end of your search path if you
1794 prefer to have user-defined names override built-in names.
1795 </para>
1797 <para>
1798 In <productname>PostgreSQL</productname> versions before 7.3,
1799 table names beginning with <literal>pg_</> were reserved. This is
1800 no longer true: you can create such a table name if you wish, in
1801 any non-system schema. However, it's best to continue to avoid
1802 such names, to ensure that you won't suffer a conflict if some
1803 future version defines a system table named the same as your
1804 table. (With the default search path, an unqualified reference to
1805 your table name would be resolved as the system table instead.)
1806 System tables will continue to follow the convention of having
1807 names beginning with <literal>pg_</>, so that they will not
1808 conflict with unqualified user-table names so long as users avoid
1809 the <literal>pg_</> prefix.
1810 </para>
1811 </sect2>
1813 <sect2 id="ddl-schemas-patterns">
1814 <title>Usage Patterns</title>
1816 <para>
1817 Schemas can be used to organize your data in many ways. There are
1818 a few usage patterns that are recommended and are easily supported by
1819 the default configuration:
1820 <itemizedlist>
1821 <listitem>
1822 <para>
1823 If you do not create any schemas then all users access the
1824 public schema implicitly. This simulates the situation where
1825 schemas are not available at all. This setup is mainly
1826 recommended when there is only a single user or a few cooperating
1827 users in a database. This setup also allows smooth transition
1828 from the non-schema-aware world.
1829 </para>
1830 </listitem>
1832 <listitem>
1833 <para>
1834 You can create a schema for each user with the same name as
1835 that user. Recall that the default search path starts with
1836 <literal>$user</literal>, which resolves to the user name.
1837 Therefore, if each user has a separate schema, they access their
1838 own schemas by default.
1839 </para>
1841 <para>
1842 If you use this setup then you might also want to revoke access
1843 to the public schema (or drop it altogether), so users are
1844 truly constrained to their own schemas.
1845 </para>
1846 </listitem>
1848 <listitem>
1849 <para>
1850 To install shared applications (tables to be used by everyone,
1851 additional functions provided by third parties, etc.), put them
1852 into separate schemas. Remember to grant appropriate
1853 privileges to allow the other users to access them. Users can
1854 then refer to these additional objects by qualifying the names
1855 with a schema name, or they can put the additional schemas into
1856 their search path, as they choose.
1857 </para>
1858 </listitem>
1859 </itemizedlist>
1860 </para>
1861 </sect2>
1863 <sect2 id="ddl-schemas-portability">
1864 <title>Portability</title>
1866 <para>
1867 In the SQL standard, the notion of objects in the same schema
1868 being owned by different users does not exist. Moreover, some
1869 implementations do not allow you to create schemas that have a
1870 different name than their owner. In fact, the concepts of schema
1871 and user are nearly equivalent in a database system that
1872 implements only the basic schema support specified in the
1873 standard. Therefore, many users consider qualified names to
1874 really consist of
1875 <literal><replaceable>username</>.<replaceable>tablename</></literal>.
1876 This is how <productname>PostgreSQL</productname> will effectively
1877 behave if you create a per-user schema for every user.
1878 </para>
1880 <para>
1881 Also, there is no concept of a <literal>public</> schema in the
1882 SQL standard. For maximum conformance to the standard, you should
1883 not use (perhaps even remove) the <literal>public</> schema.
1884 </para>
1886 <para>
1887 Of course, some SQL database systems might not implement schemas
1888 at all, or provide namespace support by allowing (possibly
1889 limited) cross-database access. If you need to work with those
1890 systems, then maximum portability would be achieved by not using
1891 schemas at all.
1892 </para>
1893 </sect2>
1894 </sect1>
1896 <sect1 id="ddl-inherit">
1897 <title>Inheritance</title>
1899 <indexterm>
1900 <primary>inheritance</primary>
1901 </indexterm>
1903 <indexterm>
1904 <primary>table</primary>
1905 <secondary>inheritance</secondary>
1906 </indexterm>
1908 <para>
1909 <productname>PostgreSQL</productname> implements table inheritance,
1910 which can be a useful tool for database designers. (SQL:1999 and
1911 later define a type inheritance feature, which differs in many
1912 respects from the features described here.)
1913 </para>
1915 <para>
1916 Let's start with an example: suppose we are trying to build a data
1917 model for cities. Each state has many cities, but only one
1918 capital. We want to be able to quickly retrieve the capital city
1919 for any particular state. This can be done by creating two tables,
1920 one for state capitals and one for cities that are not
1921 capitals. However, what happens when we want to ask for data about
1922 a city, regardless of whether it is a capital or not? The
1923 inheritance feature can help to resolve this problem. We define the
1924 <structname>capitals</structname> table so that it inherits from
1925 <structname>cities</structname>:
1927 <programlisting>
1928 CREATE TABLE cities (
1929 name text,
1930 population float,
1931 altitude int -- in feet
1934 CREATE TABLE capitals (
1935 state char(2)
1936 ) INHERITS (cities);
1937 </programlisting>
1939 In this case, the <structname>capitals</> table <firstterm>inherits</>
1940 all the columns of its parent table, <structname>cities</>. State
1941 capitals also have an extra column, <structfield>state</>, that shows
1942 their state.
1943 </para>
1945 <para>
1946 In <productname>PostgreSQL</productname>, a table can inherit from
1947 zero or more other tables, and a query can reference either all
1948 rows of a table or all rows of a table plus all of its descendant tables.
1949 The latter behavior is the default.
1950 For example, the following query finds the names of all cities,
1951 including state capitals, that are located at an altitude over
1952 500 feet:
1954 <programlisting>
1955 SELECT name, altitude
1956 FROM cities
1957 WHERE altitude &gt; 500;
1958 </programlisting>
1960 Given the sample data from the <productname>PostgreSQL</productname>
1961 tutorial (see <xref linkend="tutorial-sql-intro">), this returns:
1963 <programlisting>
1964 name | altitude
1965 -----------+----------
1966 Las Vegas | 2174
1967 Mariposa | 1953
1968 Madison | 845
1969 </programlisting>
1970 </para>
1972 <para>
1973 On the other hand, the following query finds all the cities that
1974 are not state capitals and are situated at an altitude over 500 feet:
1976 <programlisting>
1977 SELECT name, altitude
1978 FROM ONLY cities
1979 WHERE altitude &gt; 500;
1981 name | altitude
1982 -----------+----------
1983 Las Vegas | 2174
1984 Mariposa | 1953
1985 </programlisting>
1986 </para>
1988 <para>
1989 Here the <literal>ONLY</literal> keyword indicates that the query
1990 should apply only to <structname>cities</structname>, and not any tables
1991 below <structname>cities</structname> in the inheritance hierarchy. Many
1992 of the commands that we have already discussed &mdash;
1993 <command>SELECT</command>, <command>UPDATE</command> and
1994 <command>DELETE</command> &mdash; support the
1995 <literal>ONLY</literal> keyword.
1996 </para>
1998 <para>
1999 In some cases you might wish to know which table a particular row
2000 originated from. There is a system column called
2001 <structfield>tableoid</structfield> in each table which can tell you the
2002 originating table:
2004 <programlisting>
2005 SELECT c.tableoid, c.name, c.altitude
2006 FROM cities c
2007 WHERE c.altitude &gt; 500;
2008 </programlisting>
2010 which returns:
2012 <programlisting>
2013 tableoid | name | altitude
2014 ----------+-----------+----------
2015 139793 | Las Vegas | 2174
2016 139793 | Mariposa | 1953
2017 139798 | Madison | 845
2018 </programlisting>
2020 (If you try to reproduce this example, you will probably get
2021 different numeric OIDs.) By doing a join with
2022 <structname>pg_class</> you can see the actual table names:
2024 <programlisting>
2025 SELECT p.relname, c.name, c.altitude
2026 FROM cities c, pg_class p
2027 WHERE c.altitude &gt; 500 and c.tableoid = p.oid;
2028 </programlisting>
2030 which returns:
2032 <programlisting>
2033 relname | name | altitude
2034 ----------+-----------+----------
2035 cities | Las Vegas | 2174
2036 cities | Mariposa | 1953
2037 capitals | Madison | 845
2038 </programlisting>
2039 </para>
2041 <para>
2042 Inheritance does not automatically propagate data from
2043 <command>INSERT</command> or <command>COPY</command> commands to
2044 other tables in the inheritance hierarchy. In our example, the
2045 following <command>INSERT</command> statement will fail:
2046 <programlisting>
2047 INSERT INTO cities (name, population, altitude, state)
2048 VALUES ('New York', NULL, NULL, 'NY');
2049 </programlisting>
2050 We might hope that the data would somehow be routed to the
2051 <structname>capitals</structname> table, but this does not happen:
2052 <command>INSERT</command> always inserts into exactly the table
2053 specified. In some cases it is possible to redirect the insertion
2054 using a rule (see <xref linkend="rules">). However that does not
2055 help for the above case because the <structname>cities</> table
2056 does not contain the column <structfield>state</>, and so the
2057 command will be rejected before the rule can be applied.
2058 </para>
2060 <para>
2061 All check constraints and not-null constraints on a parent table are
2062 automatically inherited by its children. Other types of constraints
2063 (unique, primary key, and foreign key constraints) are not inherited.
2064 </para>
2066 <para>
2067 A table can inherit from more than one parent table, in which case it has
2068 the union of the columns defined by the parent tables. Any columns
2069 declared in the child table's definition are added to these. If the
2070 same column name appears in multiple parent tables, or in both a parent
2071 table and the child's definition, then these columns are <quote>merged</>
2072 so that there is only one such column in the child table. To be merged,
2073 columns must have the same data types, else an error is raised. The
2074 merged column will have copies of all the check constraints coming from
2075 any one of the column definitions it came from, and will be marked not-null
2076 if any of them are.
2077 </para>
2079 <para>
2080 Table inheritance is typically established when the child table is
2081 created, using the <literal>INHERITS</> clause of the
2082 <xref linkend="sql-createtable" endterm="sql-createtable-title">
2083 statement.
2084 Alternatively, a table which is already defined in a compatible way can
2085 have a new parent relationship added, using the <literal>INHERIT</literal>
2086 variant of <xref linkend="sql-altertable" endterm="sql-altertable-title">.
2087 To do this the new child table must already include columns with
2088 the same names and types as the columns of the parent. It must also include
2089 check constraints with the same names and check expressions as those of the
2090 parent. Similarly an inheritance link can be removed from a child using the
2091 <literal>NO INHERIT</literal> variant of <command>ALTER TABLE</>.
2092 Dynamically adding and removing inheritance links like this can be useful
2093 when the inheritance relationship is being used for table
2094 partitioning (see <xref linkend="ddl-partitioning">).
2095 </para>
2097 <para>
2098 One convenient way to create a compatible table that will later be made
2099 a new child is to use the <literal>LIKE</literal> clause in <command>CREATE
2100 TABLE</command>. This creates a new table with the same columns as
2101 the source table. If there are any <literal>CHECK</literal>
2102 constraints defined on the source table, the <literal>INCLUDING
2103 CONSTRAINTS</literal> option to <literal>LIKE</literal> should be
2104 specified, as the new child must have constraints matching the parent
2105 to be considered compatible.
2106 </para>
2108 <para>
2109 A parent table cannot be dropped while any of its children remain. Neither
2110 can columns or check constraints of child tables be dropped or altered
2111 if they are inherited
2112 from any parent tables. If you wish to remove a table and all of its
2113 descendants, one easy way is to drop the parent table with the
2114 <literal>CASCADE</literal> option.
2115 </para>
2117 <para>
2118 <xref linkend="sql-altertable" endterm="sql-altertable-title"> will
2119 propagate any changes in column data definitions and check
2120 constraints down the inheritance hierarchy. Again, dropping
2121 columns that are depended on by other tables is only possible when using
2122 the <literal>CASCADE</literal> option. <command>ALTER
2123 TABLE</command> follows the same rules for duplicate column merging
2124 and rejection that apply during <command>CREATE TABLE</command>.
2125 </para>
2127 <sect2 id="ddl-inherit-caveats">
2128 <title>Caveats</title>
2130 <para>
2131 Table access permissions are not automatically inherited. Therefore,
2132 a user attempting to access a parent table must either have permissions
2133 to do the operation on all its child tables as well, or must use the
2134 <literal>ONLY</literal> notation. When adding a new child table to
2135 an existing inheritance hierarchy, be careful to grant all the needed
2136 permissions on it.
2137 </para>
2139 <para>
2140 More generally, note that not all SQL commands are able to work on
2141 inheritance hierarchies. Commands that are used for data querying,
2142 data modification, or schema modification
2143 (e.g., <literal>SELECT</literal>, <literal>UPDATE</literal>, <literal>DELETE</literal>,
2144 most variants of <literal>ALTER TABLE</literal>, but
2145 not <literal>INSERT</literal> and <literal>ALTER TABLE ...
2146 RENAME</literal>) typically default to including child tables and
2147 support the <literal>ONLY</literal> notation to exclude them.
2148 Commands that do database maintenance and tuning
2149 (e.g., <literal>REINDEX</literal>, <literal>VACUUM</literal>)
2150 typically only work on individual, physical tables and do no
2151 support recursing over inheritance hierarchies. The respective
2152 behavior of each individual command is documented in the reference
2153 part (<xref linkend="sql-commands">).
2154 </para>
2156 <para>
2157 A serious limitation of the inheritance feature is that indexes (including
2158 unique constraints) and foreign key constraints only apply to single
2159 tables, not to their inheritance children. This is true on both the
2160 referencing and referenced sides of a foreign key constraint. Thus,
2161 in the terms of the above example:
2163 <itemizedlist>
2164 <listitem>
2165 <para>
2166 If we declared <structname>cities</>.<structfield>name</> to be
2167 <literal>UNIQUE</> or a <literal>PRIMARY KEY</>, this would not stop the
2168 <structname>capitals</> table from having rows with names duplicating
2169 rows in <structname>cities</>. And those duplicate rows would by
2170 default show up in queries from <structname>cities</>. In fact, by
2171 default <structname>capitals</> would have no unique constraint at all,
2172 and so could contain multiple rows with the same name.
2173 You could add a unique constraint to <structname>capitals</>, but this
2174 would not prevent duplication compared to <structname>cities</>.
2175 </para>
2176 </listitem>
2178 <listitem>
2179 <para>
2180 Similarly, if we were to specify that
2181 <structname>cities</>.<structfield>name</> <literal>REFERENCES</> some
2182 other table, this constraint would not automatically propagate to
2183 <structname>capitals</>. In this case you could work around it by
2184 manually adding the same <literal>REFERENCES</> constraint to
2185 <structname>capitals</>.
2186 </para>
2187 </listitem>
2189 <listitem>
2190 <para>
2191 Specifying that another table's column <literal>REFERENCES
2192 cities(name)</> would allow the other table to contain city names, but
2193 not capital names. There is no good workaround for this case.
2194 </para>
2195 </listitem>
2196 </itemizedlist>
2198 These deficiencies will probably be fixed in some future release,
2199 but in the meantime considerable care is needed in deciding whether
2200 inheritance is useful for your problem.
2201 </para>
2203 <note>
2204 <title>Deprecated</title>
2205 <para>
2206 In releases of <productname>PostgreSQL</productname> prior to 7.1, the
2207 default behavior was not to include child tables in queries. This was
2208 found to be error prone and also in violation of the SQL
2209 standard. You can get the pre-7.1 behavior by turning off the
2210 <xref linkend="guc-sql-inheritance"> configuration
2211 option.
2212 </para>
2213 </note>
2215 </sect2>
2216 </sect1>
2218 <sect1 id="ddl-partitioning">
2219 <title>Partitioning</title>
2221 <indexterm>
2222 <primary>partitioning</primary>
2223 </indexterm>
2225 <indexterm>
2226 <primary>table</primary>
2227 <secondary>partitioning</secondary>
2228 </indexterm>
2230 <para>
2231 <productname>PostgreSQL</productname> supports basic table
2232 partitioning. This section describes why and how to implement
2233 partitioning as part of your database design.
2234 </para>
2236 <sect2 id="ddl-partitioning-overview">
2237 <title>Overview</title>
2239 <para>
2240 Partitioning refers to splitting what is logically one large table
2241 into smaller physical pieces.
2242 Partitioning can provide several benefits:
2243 <itemizedlist>
2244 <listitem>
2245 <para>
2246 Query performance can be improved dramatically in certain situations,
2247 particularly when most of the heavily accessed rows of the table are in a
2248 single partition or a small number of partitions. The partitioning
2249 substitutes for leading columns of indexes, reducing index size and
2250 making it more likely that the heavily-used parts of the indexes
2251 fit in memory.
2252 </para>
2253 </listitem>
2255 <listitem>
2256 <para>
2257 When queries or updates access a large percentage of a single
2258 partition, performance can be improved by taking advantage
2259 of sequential scan of that partition instead of using an
2260 index and random access reads scattered across the whole table.
2261 </para>
2262 </listitem>
2264 <listitem>
2265 <para>
2266 Bulk loads and deletes can be accomplished by adding or removing
2267 partitions, if that requirement is planned into the partitioning design.
2268 <command>ALTER TABLE</> is far faster than a bulk operation.
2269 It also entirely avoids the <command>VACUUM</command>
2270 overhead caused by a bulk <command>DELETE</>.
2271 </para>
2272 </listitem>
2274 <listitem>
2275 <para>
2276 Seldom-used data can be migrated to cheaper and slower storage media.
2277 </para>
2278 </listitem>
2279 </itemizedlist>
2281 The benefits will normally be worthwhile only when a table would
2282 otherwise be very large. The exact point at which a table will
2283 benefit from partitioning depends on the application, although a
2284 rule of thumb is that the size of the table should exceed the physical
2285 memory of the database server.
2286 </para>
2288 <para>
2289 Currently, <productname>PostgreSQL</productname> supports partitioning
2290 via table inheritance. Each partition must be created as a child
2291 table of a single parent table. The parent table itself is normally
2292 empty; it exists just to represent the entire data set. You should be
2293 familiar with inheritance (see <xref linkend="ddl-inherit">) before
2294 attempting to set up partitioning.
2295 </para>
2297 <para>
2298 The following forms of partitioning can be implemented in
2299 <productname>PostgreSQL</productname>:
2301 <variablelist>
2302 <varlistentry>
2303 <term>Range Partitioning</term>
2305 <listitem>
2306 <para>
2307 The table is partitioned into <quote>ranges</quote> defined
2308 by a key column or set of columns, with no overlap between
2309 the ranges of values assigned to different partitions. For
2310 example one might partition by date ranges, or by ranges of
2311 identifiers for particular business objects.
2312 </para>
2313 </listitem>
2314 </varlistentry>
2316 <varlistentry>
2317 <term>List Partitioning</term>
2319 <listitem>
2320 <para>
2321 The table is partitioned by explicitly listing which key values
2322 appear in each partition.
2323 </para>
2324 </listitem>
2325 </varlistentry>
2326 </variablelist>
2327 </para>
2328 </sect2>
2330 <sect2 id="ddl-partitioning-implementation">
2331 <title>Implementing Partitioning</title>
2333 <para>
2334 To set up a partitioned table, do the following:
2335 <orderedlist spacing="compact">
2336 <listitem>
2337 <para>
2338 Create the <quote>master</quote> table, from which all of the
2339 partitions will inherit.
2340 </para>
2341 <para>
2342 This table will contain no data. Do not define any check
2343 constraints on this table, unless you intend them to
2344 be applied equally to all partitions. There is no point
2345 in defining any indexes or unique constraints on it, either.
2346 </para>
2347 </listitem>
2349 <listitem>
2350 <para>
2351 Create several <quote>child</quote> tables that each inherit from
2352 the master table. Normally, these tables will not add any columns
2353 to the set inherited from the master.
2354 </para>
2356 <para>
2357 We will refer to the child tables as partitions, though they
2358 are in every way normal <productname>PostgreSQL</> tables.
2359 </para>
2360 </listitem>
2362 <listitem>
2363 <para>
2364 Add table constraints to the partition tables to define the
2365 allowed key values in each partition.
2366 </para>
2368 <para>
2369 Typical examples would be:
2370 <programlisting>
2371 CHECK ( x = 1 )
2372 CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' ))
2373 CHECK ( outletID &gt;= 100 AND outletID &lt; 200 )
2374 </programlisting>
2375 Ensure that the constraints guarantee that there is no overlap
2376 between the key values permitted in different partitions. A common
2377 mistake is to set up range constraints like this:
2378 <programlisting>
2379 CHECK ( outletID BETWEEN 100 AND 200 )
2380 CHECK ( outletID BETWEEN 200 AND 300 )
2381 </programlisting>
2382 This is wrong since it is not clear which partition the key value
2383 200 belongs in.
2384 </para>
2386 <para>
2387 Note that there is no difference in
2388 syntax between range and list partitioning; those terms are
2389 descriptive only.
2390 </para>
2391 </listitem>
2393 <listitem>
2394 <para>
2395 For each partition, create an index on the key column(s),
2396 as well as any other indexes you might want. (The key index is
2397 not strictly necessary, but in most scenarios it is helpful.
2398 If you intend the key values to be unique then you should
2399 always create a unique or primary-key constraint for each
2400 partition.)
2401 </para>
2402 </listitem>
2404 <listitem>
2405 <para>
2406 Optionally, define a trigger or rule to redirect data inserted into
2407 the master table to the appropriate partition.
2408 </para>
2409 </listitem>
2411 <listitem>
2412 <para>
2413 Ensure that the <xref linkend="guc-constraint-exclusion">
2414 configuration parameter is not disabled in
2415 <filename>postgresql.conf</>.
2416 If it is, queries will not be optimized as desired.
2417 </para>
2418 </listitem>
2420 </orderedlist>
2421 </para>
2423 <para>
2424 For example, suppose we are constructing a database for a large
2425 ice cream company. The company measures peak temperatures every
2426 day as well as ice cream sales in each region. Conceptually,
2427 we want a table like this:
2429 <programlisting>
2430 CREATE TABLE measurement (
2431 city_id int not null,
2432 logdate date not null,
2433 peaktemp int,
2434 unitsales int
2436 </programlisting>
2438 We know that most queries will access just the last week's, month's or
2439 quarter's data, since the main use of this table will be to prepare
2440 online reports for management.
2441 To reduce the amount of old data that needs to be stored, we
2442 decide to only keep the most recent 3 years worth of data. At the
2443 beginning of each month we will remove the oldest month's data.
2444 </para>
2446 <para>
2447 In this situation we can use partitioning to help us meet all of our
2448 different requirements for the measurements table. Following the
2449 steps outlined above, partitioning can be set up as follows:
2450 </para>
2452 <para>
2453 <orderedlist spacing="compact">
2454 <listitem>
2455 <para>
2456 The master table is the <structname>measurement</> table, declared
2457 exactly as above.
2458 </para>
2459 </listitem>
2461 <listitem>
2462 <para>
2463 Next we create one partition for each active month:
2465 <programlisting>
2466 CREATE TABLE measurement_y2006m02 ( ) INHERITS (measurement);
2467 CREATE TABLE measurement_y2006m03 ( ) INHERITS (measurement);
2469 CREATE TABLE measurement_y2007m11 ( ) INHERITS (measurement);
2470 CREATE TABLE measurement_y2007m12 ( ) INHERITS (measurement);
2471 CREATE TABLE measurement_y2008m01 ( ) INHERITS (measurement);
2472 </programlisting>
2474 Each of the partitions are complete tables in their own right,
2475 but they inherit their definitions from the
2476 <structname>measurement</> table.
2477 </para>
2479 <para>
2480 This solves one of our problems: deleting old data. Each
2481 month, all we will need to do is perform a <command>DROP
2482 TABLE</command> on the oldest child table and create a new
2483 child table for the new month's data.
2484 </para>
2485 </listitem>
2487 <listitem>
2488 <para>
2489 We must provide non-overlapping table constraints. Rather than
2490 just creating the partition tables as above, the table creation
2491 script should really be:
2493 <programlisting>
2494 CREATE TABLE measurement_y2006m02 (
2495 CHECK ( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' )
2496 ) INHERITS (measurement);
2497 CREATE TABLE measurement_y2006m03 (
2498 CHECK ( logdate &gt;= DATE '2006-03-01' AND logdate &lt; DATE '2006-04-01' )
2499 ) INHERITS (measurement);
2501 CREATE TABLE measurement_y2007m11 (
2502 CHECK ( logdate &gt;= DATE '2007-11-01' AND logdate &lt; DATE '2007-12-01' )
2503 ) INHERITS (measurement);
2504 CREATE TABLE measurement_y2007m12 (
2505 CHECK ( logdate &gt;= DATE '2007-12-01' AND logdate &lt; DATE '2008-01-01' )
2506 ) INHERITS (measurement);
2507 CREATE TABLE measurement_y2008m01 (
2508 CHECK ( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
2509 ) INHERITS (measurement);
2510 </programlisting>
2511 </para>
2512 </listitem>
2514 <listitem>
2515 <para>
2516 We probably need indexes on the key columns too:
2518 <programlisting>
2519 CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate);
2520 CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate);
2522 CREATE INDEX measurement_y2007m11_logdate ON measurement_y2007m11 (logdate);
2523 CREATE INDEX measurement_y2007m12_logdate ON measurement_y2007m12 (logdate);
2524 CREATE INDEX measurement_y2008m01_logdate ON measurement_y2008m01 (logdate);
2525 </programlisting>
2527 We choose not to add further indexes at this time.
2528 </para>
2529 </listitem>
2531 <listitem>
2532 <para>
2533 We want our application to be able to say <literal>INSERT INTO
2534 measurement ...</> and have the data be redirected into the
2535 appropriate partition table. We can arrange that by attaching
2536 a suitable trigger function to the master table.
2537 If data will be added only to the latest partition, we can
2538 use a very simple trigger function:
2540 <programlisting>
2541 CREATE OR REPLACE FUNCTION measurement_insert_trigger()
2542 RETURNS TRIGGER AS $$
2543 BEGIN
2544 INSERT INTO measurement_y2008m01 VALUES (NEW.*);
2545 RETURN NULL;
2546 END;
2548 LANGUAGE plpgsql;
2549 </programlisting>
2551 After creating the function, we create a trigger which
2552 calls the trigger function:
2554 <programlisting>
2555 CREATE TRIGGER insert_measurement_trigger
2556 BEFORE INSERT ON measurement
2557 FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger();
2558 </programlisting>
2560 We must redefine the trigger function each month so that it always
2561 points to the current partition. The trigger definition does
2562 not need to be updated, however.
2563 </para>
2565 <para>
2566 We might want to insert data and have the server automatically
2567 locate the partition into which the row should be added. We
2568 could do this with a more complex trigger function, for example:
2570 <programlisting>
2571 CREATE OR REPLACE FUNCTION measurement_insert_trigger()
2572 RETURNS TRIGGER AS $$
2573 BEGIN
2574 IF ( NEW.logdate &gt;= DATE '2006-02-01' AND NEW.logdate &lt; DATE '2006-03-01' ) THEN
2575 INSERT INTO measurement_y2006m02 VALUES (NEW.*);
2576 ELSIF ( NEW.logdate &gt;= DATE '2006-03-01' AND NEW.logdate &lt; DATE '2006-04-01' ) THEN
2577 INSERT INTO measurement_y2006m03 VALUES (NEW.*);
2579 ELSIF ( NEW.logdate &gt;= DATE '2008-01-01' AND NEW.logdate &lt; DATE '2008-02-01' ) THEN
2580 INSERT INTO measurement_y2008m01 VALUES (NEW.*);
2581 ELSE
2582 RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!';
2583 END IF;
2584 RETURN NULL;
2585 END;
2587 LANGUAGE plpgsql;
2588 </programlisting>
2590 The trigger definition is the same as before.
2591 Note that each <literal>IF</literal> test must exactly match the
2592 <literal>CHECK</literal> constraint for its partition.
2593 </para>
2595 <para>
2596 While this function is more complex than the single-month case,
2597 it doesn't need to be updated as often, since branches can be
2598 added in advance of being needed.
2599 </para>
2601 <note>
2602 <para>
2603 In practice it might be best to check the newest partition first,
2604 if most inserts go into that partition. For simplicity we have
2605 shown the trigger's tests in the same order as in other parts
2606 of this example.
2607 </para>
2608 </note>
2609 </listitem>
2610 </orderedlist>
2611 </para>
2613 <para>
2614 As we can see, a complex partitioning scheme could require a
2615 substantial amount of DDL. In the above example we would be
2616 creating a new partition each month, so it might be wise to write a
2617 script that generates the required DDL automatically.
2618 </para>
2620 </sect2>
2622 <sect2 id="ddl-partitioning-managing-partitions">
2623 <title>Managing Partitions</title>
2625 <para>
2626 Normally the set of partitions established when initially
2627 defining the table are not intended to remain static. It is
2628 common to want to remove old partitions of data and periodically
2629 add new partitions for new data. One of the most important
2630 advantages of partitioning is precisely that it allows this
2631 otherwise painful task to be executed nearly instantaneously by
2632 manipulating the partition structure, rather than physically moving large
2633 amounts of data around.
2634 </para>
2636 <para>
2637 The simplest option for removing old data is simply to drop the partition
2638 that is no longer necessary:
2639 <programlisting>
2640 DROP TABLE measurement_y2006m02;
2641 </programlisting>
2642 This can very quickly delete millions of records because it doesn't have
2643 to individually delete every record.
2644 </para>
2646 <para>
2647 Another option that is often preferable is to remove the partition from
2648 the partitioned table but retain access to it as a table in its own
2649 right:
2650 <programlisting>
2651 ALTER TABLE measurement_y2006m02 NO INHERIT measurement;
2652 </programlisting>
2653 This allows further operations to be performed on the data before
2654 it is dropped. For example, this is often a useful time to back up
2655 the data using <command>COPY</>, <application>pg_dump</>, or
2656 similar tools. It might also be a useful time to aggregate data
2657 into smaller formats, perform other data manipulations, or run
2658 reports.
2659 </para>
2661 <para>
2662 Similarly we can add a new partition to handle new data. We can create an
2663 empty partition in the partitioned table just as the original partitions
2664 were created above:
2666 <programlisting>
2667 CREATE TABLE measurement_y2008m02 (
2668 CHECK ( logdate &gt;= DATE '2008-02-01' AND logdate &lt; DATE '2008-03-01' )
2669 ) INHERITS (measurement);
2670 </programlisting>
2672 As an alternative, it is sometimes more convenient to create the
2673 new table outside the partition structure, and make it a proper
2674 partition later. This allows the data to be loaded, checked, and
2675 transformed prior to it appearing in the partitioned table:
2677 <programlisting>
2678 CREATE TABLE measurement_y2008m02
2679 (LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS);
2680 ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
2681 CHECK ( logdate &gt;= DATE '2008-02-01' AND logdate &lt; DATE '2008-03-01' );
2682 \copy measurement_y2008m02 from 'measurement_y2008m02'
2683 -- possibly some other data preparation work
2684 ALTER TABLE measurement_y2008m02 INHERIT measurement;
2685 </programlisting>
2686 </para>
2687 </sect2>
2689 <sect2 id="ddl-partitioning-constraint-exclusion">
2690 <title>Partitioning and Constraint Exclusion</title>
2692 <indexterm>
2693 <primary>constraint exclusion</primary>
2694 </indexterm>
2696 <para>
2697 <firstterm>Constraint exclusion</> is a query optimization technique
2698 that improves performance for partitioned tables defined in the
2699 fashion described above. As an example:
2701 <programlisting>
2702 SET constraint_exclusion = on;
2703 SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
2704 </programlisting>
2706 Without constraint exclusion, the above query would scan each of
2707 the partitions of the <structname>measurement</> table. With constraint
2708 exclusion enabled, the planner will examine the constraints of each
2709 partition and try to prove that the partition need not
2710 be scanned because it could not contain any rows meeting the query's
2711 <literal>WHERE</> clause. When the planner can prove this, it
2712 excludes the partition from the query plan.
2713 </para>
2715 <para>
2716 You can use the <command>EXPLAIN</> command to show the difference
2717 between a plan with <varname>constraint_exclusion</> on and a plan
2718 with it off. A typical unoptimized plan for this type of table setup is:
2720 <programlisting>
2721 SET constraint_exclusion = off;
2722 EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
2724 QUERY PLAN
2725 -----------------------------------------------------------------------------------------------
2726 Aggregate (cost=158.66..158.68 rows=1 width=0)
2727 -&gt; Append (cost=0.00..151.88 rows=2715 width=0)
2728 -&gt; Seq Scan on measurement (cost=0.00..30.38 rows=543 width=0)
2729 Filter: (logdate &gt;= '2008-01-01'::date)
2730 -&gt; Seq Scan on measurement_y2006m02 measurement (cost=0.00..30.38 rows=543 width=0)
2731 Filter: (logdate &gt;= '2008-01-01'::date)
2732 -&gt; Seq Scan on measurement_y2006m03 measurement (cost=0.00..30.38 rows=543 width=0)
2733 Filter: (logdate &gt;= '2008-01-01'::date)
2735 -&gt; Seq Scan on measurement_y2007m12 measurement (cost=0.00..30.38 rows=543 width=0)
2736 Filter: (logdate &gt;= '2008-01-01'::date)
2737 -&gt; Seq Scan on measurement_y2008m01 measurement (cost=0.00..30.38 rows=543 width=0)
2738 Filter: (logdate &gt;= '2008-01-01'::date)
2739 </programlisting>
2741 Some or all of the partitions might use index scans instead of
2742 full-table sequential scans, but the point here is that there
2743 is no need to scan the older partitions at all to answer this query.
2744 When we enable constraint exclusion, we get a significantly
2745 cheaper plan that will deliver the same answer:
2747 <programlisting>
2748 SET constraint_exclusion = on;
2749 EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
2750 QUERY PLAN
2751 -----------------------------------------------------------------------------------------------
2752 Aggregate (cost=63.47..63.48 rows=1 width=0)
2753 -&gt; Append (cost=0.00..60.75 rows=1086 width=0)
2754 -&gt; Seq Scan on measurement (cost=0.00..30.38 rows=543 width=0)
2755 Filter: (logdate &gt;= '2008-01-01'::date)
2756 -&gt; Seq Scan on measurement_y2008m01 measurement (cost=0.00..30.38 rows=543 width=0)
2757 Filter: (logdate &gt;= '2008-01-01'::date)
2758 </programlisting>
2759 </para>
2761 <para>
2762 Note that constraint exclusion is driven only by <literal>CHECK</>
2763 constraints, not by the presence of indexes. Therefore it isn't
2764 necessary to define indexes on the key columns. Whether an index
2765 needs to be created for a given partition depends on whether you
2766 expect that queries that scan the partition will generally scan
2767 a large part of the partition or just a small part. An index will
2768 be helpful in the latter case but not the former.
2769 </para>
2771 <para>
2772 The default (and recommended) setting of
2773 <xref linkend="guc-constraint-exclusion"> is actually neither
2774 <literal>on</> nor <literal>off</>, but an intermediate setting
2775 called <literal>partition</>, which causes the technique to be
2776 applied only to queries that are likely to be working on partitioned
2777 tables. The <literal>on</> setting causes the planner to examine
2778 <literal>CHECK</> constraints in all queries, even simple ones that
2779 are unlikely to benefit.
2780 </para>
2782 </sect2>
2784 <sect2 id="ddl-partitioning-alternatives">
2785 <title>Alternative Partitioning Methods</title>
2787 <para>
2788 A different approach to redirecting inserts into the appropriate
2789 partition table is to set up rules, instead of a trigger, on the
2790 master table. For example:
2792 <programlisting>
2793 CREATE RULE measurement_insert_y2006m02 AS
2794 ON INSERT TO measurement WHERE
2795 ( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' )
2796 DO INSTEAD
2797 INSERT INTO measurement_y2006m02 VALUES (NEW.*);
2799 CREATE RULE measurement_insert_y2008m01 AS
2800 ON INSERT TO measurement WHERE
2801 ( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
2802 DO INSTEAD
2803 INSERT INTO measurement_y2008m01 VALUES (NEW.*);
2804 </programlisting>
2806 A rule has significantly more overhead than a trigger, but the overhead
2807 is paid once per query rather than once per row, so this method might be
2808 advantageous for bulk-insert situations. In most cases, however, the
2809 trigger method will offer better performance.
2810 </para>
2812 <para>
2813 Be aware that <command>COPY</> ignores rules. If you want to
2814 use <command>COPY</> to insert data, you'll need to copy into the correct
2815 partition table rather than into the master. <command>COPY</> does fire
2816 triggers, so you can use it normally if you use the trigger approach.
2817 </para>
2819 <para>
2820 Another disadvantage of the rule approach is that there is no simple
2821 way to force an error if the set of rules doesn't cover the insertion
2822 date; the data will silently go into the master table instead.
2823 </para>
2825 <para>
2826 Partitioning can also be arranged using a <literal>UNION ALL</literal>
2827 view, instead of table inheritance. For example,
2829 <programlisting>
2830 CREATE VIEW measurement AS
2831 SELECT * FROM measurement_y2006m02
2832 UNION ALL SELECT * FROM measurement_y2006m03
2834 UNION ALL SELECT * FROM measurement_y2007m11
2835 UNION ALL SELECT * FROM measurement_y2007m12
2836 UNION ALL SELECT * FROM measurement_y2008m01;
2837 </programlisting>
2839 However, the need to recreate the view adds an extra step to adding and
2840 dropping individual partitions of the data set. In practice this
2841 method has little to recommend it compared to using inheritance.
2842 </para>
2844 </sect2>
2846 <sect2 id="ddl-partitioning-caveats">
2847 <title>Caveats</title>
2849 <para>
2850 The following caveats apply to partitioned tables:
2851 <itemizedlist>
2852 <listitem>
2853 <para>
2854 There is no automatic way to verify that all of the
2855 <literal>CHECK</literal> constraints are mutually
2856 exclusive. It is safer to create code that generates
2857 partitions and creates and/or modifies associated objects than
2858 to write each by hand.
2859 </para>
2860 </listitem>
2862 <listitem>
2863 <para>
2864 The schemes shown here assume that the partition key column(s)
2865 of a row never change, or at least do not change enough to require
2866 it to move to another partition. An <command>UPDATE</> that attempts
2867 to do that will fail because of the <literal>CHECK</> constraints.
2868 If you need to handle such cases, you can put suitable update triggers
2869 on the partition tables, but it makes management of the structure
2870 much more complicated.
2871 </para>
2872 </listitem>
2874 <listitem>
2875 <para>
2876 If you are using manual <command>VACUUM</command> or
2877 <command>ANALYZE</command> commands, don't forget that
2878 you need to run them on each partition individually. A command like
2879 <programlisting>
2880 ANALYZE measurement;
2881 </programlisting>
2882 will only process the master table.
2883 </para>
2884 </listitem>
2886 </itemizedlist>
2887 </para>
2889 <para>
2890 The following caveats apply to constraint exclusion:
2892 <itemizedlist>
2893 <listitem>
2894 <para>
2895 Constraint exclusion only works when the query's <literal>WHERE</>
2896 clause contains constants. A parameterized query will not be
2897 optimized, since the planner cannot know which partitions the
2898 parameter value might select at run time. For the same reason,
2899 <quote>stable</> functions such as <function>CURRENT_DATE</function>
2900 must be avoided.
2901 </para>
2902 </listitem>
2904 <listitem>
2905 <para>
2906 Keep the partitioning constraints simple, else the planner may not be
2907 able to prove that partitions don't need to be visited. Use simple
2908 equality conditions for list partitioning, or simple
2909 range tests for range partitioning, as illustrated in the preceding
2910 examples. A good rule of thumb is that partitioning constraints should
2911 contain only comparisons of the partitioning column(s) to constants
2912 using B-tree-indexable operators.
2913 </para>
2914 </listitem>
2916 <listitem>
2917 <para>
2918 All constraints on all partitions of the master table are examined
2919 during constraint exclusion, so large numbers of partitions are likely
2920 to increase query planning time considerably. Partitioning using
2921 these techniques will work well with up to perhaps a hundred partitions;
2922 don't try to use many thousands of partitions.
2923 </para>
2924 </listitem>
2926 </itemizedlist>
2927 </para>
2928 </sect2>
2929 </sect1>
2931 <sect1 id="ddl-others">
2932 <title>Other Database Objects</title>
2934 <para>
2935 Tables are the central objects in a relational database structure,
2936 because they hold your data. But they are not the only objects
2937 that exist in a database. Many other kinds of objects can be
2938 created to make the use and management of the data more efficient
2939 or convenient. They are not discussed in this chapter, but we give
2940 you a list here so that you are aware of what is possible.
2941 </para>
2943 <itemizedlist>
2944 <listitem>
2945 <para>
2946 Views
2947 </para>
2948 </listitem>
2950 <listitem>
2951 <para>
2952 Functions and operators
2953 </para>
2954 </listitem>
2956 <listitem>
2957 <para>
2958 Data types and domains
2959 </para>
2960 </listitem>
2962 <listitem>
2963 <para>
2964 Triggers and rewrite rules
2965 </para>
2966 </listitem>
2967 </itemizedlist>
2969 <para>
2970 Detailed information on
2971 these topics appears in <xref linkend="server-programming">.
2972 </para>
2973 </sect1>
2975 <sect1 id="ddl-depend">
2976 <title>Dependency Tracking</title>
2978 <indexterm zone="ddl-depend">
2979 <primary>CASCADE</primary>
2980 <secondary sortas="DROP">with DROP</secondary>
2981 </indexterm>
2983 <indexterm zone="ddl-depend">
2984 <primary>RESTRICT</primary>
2985 <secondary sortas="DROP">with DROP</secondary>
2986 </indexterm>
2988 <para>
2989 When you create complex database structures involving many tables
2990 with foreign key constraints, views, triggers, functions, etc. you
2991 will implicitly create a net of dependencies between the objects.
2992 For instance, a table with a foreign key constraint depends on the
2993 table it references.
2994 </para>
2996 <para>
2997 To ensure the integrity of the entire database structure,
2998 <productname>PostgreSQL</productname> makes sure that you cannot
2999 drop objects that other objects still depend on. For example,
3000 attempting to drop the products table we had considered in <xref
3001 linkend="ddl-constraints-fk">, with the orders table depending on
3002 it, would result in an error message such as this:
3003 <screen>
3004 DROP TABLE products;
3006 NOTICE: constraint orders_product_no_fkey on table orders depends on table products
3007 ERROR: cannot drop table products because other objects depend on it
3008 HINT: Use DROP ... CASCADE to drop the dependent objects too.
3009 </screen>
3010 The error message contains a useful hint: if you do not want to
3011 bother deleting all the dependent objects individually, you can run
3012 <screen>
3013 DROP TABLE products CASCADE;
3014 </screen>
3015 and all the dependent objects will be removed. In this case, it
3016 doesn't remove the orders table, it only removes the foreign key
3017 constraint. (If you want to check what <command>DROP ... CASCADE</> will do,
3018 run <command>DROP</> without <literal>CASCADE</> and read the <literal>NOTICE</> messages.)
3019 </para>
3021 <para>
3022 All drop commands in <productname>PostgreSQL</productname> support
3023 specifying <literal>CASCADE</literal>. Of course, the nature of
3024 the possible dependencies varies with the type of the object. You
3025 can also write <literal>RESTRICT</literal> instead of
3026 <literal>CASCADE</literal> to get the default behavior, which is to
3027 prevent drops of objects that other objects depend on.
3028 </para>
3030 <note>
3031 <para>
3032 According to the SQL standard, specifying either
3033 <literal>RESTRICT</literal> or <literal>CASCADE</literal> is
3034 required. No database system actually enforces that rule, but
3035 whether the default behavior is <literal>RESTRICT</literal> or
3036 <literal>CASCADE</literal> varies across systems.
3037 </para>
3038 </note>
3040 <note>
3041 <para>
3042 Foreign key constraint dependencies and serial column dependencies
3043 from <productname>PostgreSQL</productname> versions prior to 7.3
3044 are <emphasis>not</emphasis> maintained or created during the
3045 upgrade process. All other dependency types will be properly
3046 created during an upgrade from a pre-7.3 database.
3047 </para>
3048 </note>
3049 </sect1>
3051 </chapter>