1 <!-- doc/src/sgml/ddl.sgml -->
4 <title>Data Definition
</title>
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, table partitioning, views, functions, and
19 <sect1 id=
"ddl-basics">
20 <title>Table Basics
</title>
22 <indexterm zone=
"ddl-basics">
23 <primary>table
</primary>
27 <primary>row
</primary>
31 <primary>column
</primary>
35 A table in a relational database is much like a table on paper: It
36 consists of rows and columns. The number and order of the columns
37 is fixed, and each column has a name. The number of rows is
38 variable
— it reflects how much data is stored at a given moment.
39 SQL does not make any guarantees about the order of the rows in a
40 table. When a table is read, the rows will appear in an unspecified order,
41 unless sorting is explicitly requested. This is covered in
<xref
42 linkend=
"queries"/>. Furthermore, SQL does not assign unique
43 identifiers to rows, so it is possible to have several completely
44 identical rows in a table. This is a consequence of the
45 mathematical model that underlies SQL but is usually not desirable.
46 Later in this chapter we will see how to deal with this issue.
50 Each column has a data type. The data type constrains the set of
51 possible values that can be assigned to a column and assigns
52 semantics to the data stored in the column so that it can be used
53 for computations. For instance, a column declared to be of a
54 numerical type will not accept arbitrary text strings, and the data
55 stored in such a column can be used for mathematical computations.
56 By contrast, a column declared to be of a character string type
57 will accept almost any kind of data but it does not lend itself to
58 mathematical calculations, although other operations such as string
59 concatenation are available.
63 <productname>PostgreSQL
</productname> includes a sizable set of
64 built-in data types that fit many applications. Users can also
65 define their own data types. Most built-in data types have obvious
66 names and semantics, so we defer a detailed explanation to
<xref
67 linkend=
"datatype"/>. Some of the frequently used data types are
68 <type>integer
</type> for whole numbers,
<type>numeric
</type> for
69 possibly fractional numbers,
<type>text
</type> for character
70 strings,
<type>date
</type> for dates,
<type>time
</type> for
71 time-of-day values, and
<type>timestamp
</type> for values
72 containing both date and time.
76 <primary>table
</primary>
77 <secondary>creating
</secondary>
81 To create a table, you use the aptly named
<xref
82 linkend=
"sql-createtable"/> command.
83 In this command you specify at least a name for the new table, the
84 names of the columns and the data type of each column. For
87 CREATE TABLE my_first_table (
92 This creates a table named
<literal>my_first_table
</literal> with
93 two columns. The first column is named
94 <literal>first_column
</literal> and has a data type of
95 <type>text
</type>; the second column has the name
96 <literal>second_column
</literal> and the type
<type>integer
</type>.
97 The table and column names follow the identifier syntax explained
98 in
<xref linkend=
"sql-syntax-identifiers"/>. The type names are
99 usually also identifiers, but there are some exceptions. Note that the
100 column list is comma-separated and surrounded by parentheses.
104 Of course, the previous example was heavily contrived. Normally,
105 you would give names to your tables and columns that convey what
106 kind of data they store. So let's look at a more realistic
109 CREATE TABLE products (
115 (The
<type>numeric
</type> type can store fractional components, as
116 would be typical of monetary amounts.)
121 When you create many interrelated tables it is wise to choose a
122 consistent naming pattern for the tables and columns. For
123 instance, there is a choice of using singular or plural nouns for
124 table names, both of which are favored by some theorist or other.
129 There is a limit on how many columns a table can contain.
130 Depending on the column types, it is between
250 and
1600.
131 However, defining a table with anywhere near this many columns is
132 highly unusual and often a questionable design.
136 <primary>table
</primary>
137 <secondary>removing
</secondary>
141 If you no longer need a table, you can remove it using the
<xref
142 linkend=
"sql-droptable"/> command.
145 DROP TABLE my_first_table;
148 Attempting to drop a table that does not exist is an error.
149 Nevertheless, it is common in SQL script files to unconditionally
150 try to drop each table before creating it, ignoring any error
151 messages, so that the script works whether or not the table exists.
152 (If you like, you can use the
<literal>DROP TABLE IF EXISTS
</literal> variant
153 to avoid the error messages, but this is not standard SQL.)
157 If you need to modify a table that already exists, see
<xref
158 linkend=
"ddl-alter"/> later in this chapter.
162 With the tools discussed so far you can create fully functional
163 tables. The remainder of this chapter is concerned with adding
164 features to the table definition to ensure data integrity,
165 security, or convenience. If you are eager to fill your tables with
166 data now you can skip ahead to
<xref linkend=
"dml"/> and read the
167 rest of this chapter later.
171 <sect1 id=
"ddl-default">
172 <title>Default Values
</title>
174 <indexterm zone=
"ddl-default">
175 <primary>default value
</primary>
179 A column can be assigned a default value. When a new row is
180 created and no values are specified for some of the columns, those
181 columns will be filled with their respective default values. A
182 data manipulation command can also request explicitly that a column
183 be set to its default value, without having to know what that value is.
184 (Details about data manipulation commands are in
<xref linkend=
"dml"/>.)
188 <indexterm><primary>null value
</primary><secondary>default value
</secondary></indexterm>
189 If no default value is declared explicitly, the default value is the
190 null value. This usually makes sense because a null value can
191 be considered to represent unknown data.
195 In a table definition, default values are listed after the column
196 data type. For example:
198 CREATE TABLE products (
201 price numeric
<emphasis>DEFAULT
9.99</emphasis>
207 The default value can be an expression, which will be
208 evaluated whenever the default value is inserted
209 (
<emphasis>not
</emphasis> when the table is created). A common example
210 is for a
<type>timestamp
</type> column to have a default of
<literal>CURRENT_TIMESTAMP
</literal>,
211 so that it gets set to the time of row insertion. Another common
212 example is generating a
<quote>serial number
</quote> for each row.
213 In
<productname>PostgreSQL
</productname> this is typically done by
216 CREATE TABLE products (
217 product_no integer
<emphasis>DEFAULT nextval('products_product_no_seq')
</emphasis>,
221 where the
<literal>nextval()
</literal> function supplies successive values
222 from a
<firstterm>sequence object
</firstterm> (see
<xref
223 linkend=
"functions-sequence"/>). This arrangement is sufficiently common
224 that there's a special shorthand for it:
226 CREATE TABLE products (
227 product_no
<emphasis>SERIAL
</emphasis>,
231 The
<literal>SERIAL
</literal> shorthand is discussed further in
<xref
232 linkend=
"datatype-serial"/>.
236 <sect1 id=
"ddl-identity-columns">
237 <title>Identity Columns
</title>
239 <indexterm zone=
"ddl-identity-columns">
240 <primary>identity column
</primary>
244 An identity column is a special column that is generated automatically from
245 an implicit sequence. It can be used to generate key values.
249 To create an identity column, use the
<literal>GENERATED ...
250 AS IDENTITY
</literal> clause in
<command>CREATE TABLE
</command>, for example:
252 CREATE TABLE people (
253 id bigint
<emphasis>GENERATED ALWAYS AS IDENTITY
</emphasis>,
259 CREATE TABLE people (
260 id bigint
<emphasis>GENERATED BY DEFAULT AS IDENTITY
</emphasis>,
264 See
<xref linkend=
"sql-createtable"/> for more details.
268 If an
<command>INSERT
</command> command is executed on the table with the
269 identity column and no value is explicitly specified for the identity
270 column, then a value generated by the implicit sequence is inserted. For
271 example, with the above definitions and assuming additional appropriate
274 INSERT INTO people (name, address) VALUES ('A', 'foo');
275 INSERT INTO people (name, address) VALUES ('B', 'bar');
277 would generate values for the
<literal>id
</literal> column starting at
1
278 and result in the following table data:
281 ----+------+---------
285 Alternatively, the keyword
<literal>DEFAULT
</literal> can be specified in
286 place of a value to explicitly request the sequence-generated value, like
288 INSERT INTO people (id, name, address) VALUES (
<emphasis>DEFAULT
</emphasis>, 'C', 'baz');
290 Similarly, the keyword
<literal>DEFAULT
</literal> can be used in
291 <command>UPDATE
</command> commands.
295 Thus, in many ways, an identity column behaves like a column with a default
300 The clauses
<literal>ALWAYS
</literal> and
<literal>BY DEFAULT
</literal> in
301 the column definition determine how explicitly user-specified values are
302 handled in
<command>INSERT
</command> and
<command>UPDATE
</command>
303 commands. In an
<command>INSERT
</command> command, if
304 <literal>ALWAYS
</literal> is selected, a user-specified value is only
305 accepted if the
<command>INSERT
</command> statement specifies
306 <literal>OVERRIDING SYSTEM VALUE
</literal>. If
<literal>BY
307 DEFAULT
</literal> is selected, then the user-specified value takes
308 precedence. Thus, using
<literal>BY DEFAULT
</literal> results in a
309 behavior more similar to default values, where the default value can be
310 overridden by an explicit value, whereas
<literal>ALWAYS
</literal> provides
311 some more protection against accidentally inserting an explicit value.
315 The data type of an identity column must be one of the data types supported
316 by sequences. (See
<xref linkend=
"sql-createsequence"/>.) The properties
317 of the associated sequence may be specified when creating an identity
318 column (see
<xref linkend=
"sql-createtable"/>) or changed afterwards (see
319 <xref linkend=
"sql-altertable"/>).
323 An identity column is automatically marked as
<literal>NOT NULL
</literal>.
324 An identity column, however, does not guarantee uniqueness. (A sequence
325 normally returns unique values, but a sequence could be reset, or values
326 could be inserted manually into the identity column, as discussed above.)
327 Uniqueness would need to be enforced using a
<literal>PRIMARY KEY
</literal>
328 or
<literal>UNIQUE
</literal> constraint.
332 In table inheritance hierarchies, identity columns and their properties in
333 a child table are independent of those in its parent tables. A child table
334 does not inherit identity columns or their properties automatically from
335 the parent. During
<command>INSERT
</command> or
<command>UPDATE
</command>,
336 a column is treated as an identity column if that column is an identity
337 column in the table named in the statement, and the corresponding identity
338 properties are applied.
342 Partitions inherit identity columns from the partitioned table. They
343 cannot have their own identity columns. The properties of a given identity
344 column are consistent across all the partitions in the partition hierarchy.
348 <sect1 id=
"ddl-generated-columns">
349 <title>Generated Columns
</title>
351 <indexterm zone=
"ddl-generated-columns">
352 <primary>generated column
</primary>
356 A generated column is a special column that is always computed from other
357 columns. Thus, it is for columns what a view is for tables. There are two
358 kinds of generated columns: stored and virtual. A stored generated column
359 is computed when it is written (inserted or updated) and occupies storage
360 as if it were a normal column. A virtual generated column occupies no
361 storage and is computed when it is read. Thus, a virtual generated column
362 is similar to a view and a stored generated column is similar to a
363 materialized view (except that it is always updated automatically).
364 <productname>PostgreSQL
</productname> currently implements only stored generated columns.
368 To create a generated column, use the
<literal>GENERATED ALWAYS
369 AS
</literal> clause in
<command>CREATE TABLE
</command>, for example:
371 CREATE TABLE people (
374 height_in numeric
<emphasis>GENERATED ALWAYS AS (height_cm /
2.54) STORED
</emphasis>
377 The keyword
<literal>STORED
</literal> must be specified to choose the
378 stored kind of generated column. See
<xref linkend=
"sql-createtable"/> for
383 A generated column cannot be written to directly. In
384 <command>INSERT
</command> or
<command>UPDATE
</command> commands, a value
385 cannot be specified for a generated column, but the keyword
386 <literal>DEFAULT
</literal> may be specified.
390 Consider the differences between a column with a default and a generated
391 column. The column default is evaluated once when the row is first
392 inserted if no other value was provided; a generated column is updated
393 whenever the row changes and cannot be overridden. A column default may
394 not refer to other columns of the table; a generation expression would
395 normally do so. A column default can use volatile functions, for example
396 <literal>random()
</literal> or functions referring to the current time;
397 this is not allowed for generated columns.
401 Several restrictions apply to the definition of generated columns and
402 tables involving generated columns:
407 The generation expression can only use immutable functions and cannot
408 use subqueries or reference anything other than the current row in any
414 A generation expression cannot reference another generated column.
419 A generation expression cannot reference a system column, except
420 <varname>tableoid
</varname>.
425 A generated column cannot have a column default or an identity definition.
430 A generated column cannot be part of a partition key.
435 Foreign tables can have generated columns. See
<xref
436 linkend=
"sql-createforeigntable"/> for details.
440 <para>For inheritance and partitioning:
</para>
444 If a parent column is a generated column, its child column must also
445 be a generated column; however, the child column can have a
446 different generation expression. The generation expression that is
447 actually applied during insert or update of a row is the one
448 associated with the table that the row is physically in.
449 (This is unlike the behavior for column defaults: for those, the
450 default value associated with the table named in the query applies.)
455 If a parent column is not a generated column, its child column must
456 not be generated either.
461 For inherited tables, if you write a child column definition without
462 any
<literal>GENERATED
</literal> clause in
<command>CREATE TABLE
463 ... INHERITS
</command>, then its
<literal>GENERATED
</literal> clause
464 will automatically be copied from the parent.
<command>ALTER TABLE
465 ... INHERIT
</command> will insist that parent and child columns
466 already match as to generation status, but it will not require their
467 generation expressions to match.
472 Similarly for partitioned tables, if you write a child column
473 definition without any
<literal>GENERATED
</literal> clause
474 in
<command>CREATE TABLE ... PARTITION OF
</command>, then
475 its
<literal>GENERATED
</literal> clause will automatically be copied
476 from the parent.
<command>ALTER TABLE ... ATTACH PARTITION
</command>
477 will insist that parent and child columns already match as to
478 generation status, but it will not require their generation
479 expressions to match.
484 In case of multiple inheritance, if one parent column is a generated
485 column, then all parent columns must be generated columns. If they
486 do not all have the same generation expression, then the desired
487 expression for the child must be specified explicitly.
496 Additional considerations apply to the use of generated columns.
500 Generated columns maintain access privileges separately from their
501 underlying base columns. So, it is possible to arrange it so that a
502 particular role can read from a generated column but not from the
503 underlying base columns.
508 Generated columns are, conceptually, updated after
509 <literal>BEFORE
</literal> triggers have run. Therefore, changes made to
510 base columns in a
<literal>BEFORE
</literal> trigger will be reflected in
511 generated columns. But conversely, it is not allowed to access
512 generated columns in
<literal>BEFORE
</literal> triggers.
517 Generated columns are allowed to be replicated during logical replication
518 according to the
<command>CREATE PUBLICATION
</command> parameter
519 <link linkend=
"sql-createpublication-params-with-publish-generated-columns">
520 <literal>publish_generated_columns
</literal></link> or by including them
521 in the column list of the
<command>CREATE PUBLICATION
</command> command.
522 See
<xref linkend=
"logical-replication-gencols"/> for details.
529 <sect1 id=
"ddl-constraints">
530 <title>Constraints
</title>
532 <indexterm zone=
"ddl-constraints">
533 <primary>constraint
</primary>
537 Data types are a way to limit the kind of data that can be stored
538 in a table. For many applications, however, the constraint they
539 provide is too coarse. For example, a column containing a product
540 price should probably only accept positive values. But there is no
541 standard data type that accepts only positive numbers. Another issue is
542 that you might want to constrain column data with respect to other
543 columns or rows. For example, in a table containing product
544 information, there should be only one row for each product number.
548 To that end, SQL allows you to define constraints on columns and
549 tables. Constraints give you as much control over the data in your
550 tables as you wish. If a user attempts to store data in a column
551 that would violate a constraint, an error is raised. This applies
552 even if the value came from the default value definition.
555 <sect2 id=
"ddl-constraints-check-constraints">
556 <title>Check Constraints
</title>
559 <primary>check constraint
</primary>
563 <primary>constraint
</primary>
564 <secondary>check
</secondary>
568 A check constraint is the most generic constraint type. It allows
569 you to specify that the value in a certain column must satisfy a
570 Boolean (truth-value) expression. For instance, to require positive
571 product prices, you could use:
573 CREATE TABLE products (
576 price numeric
<emphasis>CHECK (price
> 0)
</emphasis>
582 As you see, the constraint definition comes after the data type,
583 just like default value definitions. Default values and
584 constraints can be listed in any order. A check constraint
585 consists of the key word
<literal>CHECK
</literal> followed by an
586 expression in parentheses. The check constraint expression should
587 involve the column thus constrained, otherwise the constraint
588 would not make too much sense.
592 <primary>constraint
</primary>
593 <secondary>name
</secondary>
597 You can also give the constraint a separate name. This clarifies
598 error messages and allows you to refer to the constraint when you
599 need to change it. The syntax is:
601 CREATE TABLE products (
604 price numeric
<emphasis>CONSTRAINT positive_price
</emphasis> CHECK (price
> 0)
607 So, to specify a named constraint, use the key word
608 <literal>CONSTRAINT
</literal> followed by an identifier followed
609 by the constraint definition. (If you don't specify a constraint
610 name in this way, the system chooses a name for you.)
614 A check constraint can also refer to several columns. Say you
615 store a regular price and a discounted price, and you want to
616 ensure that the discounted price is lower than the regular price:
618 CREATE TABLE products (
621 price numeric CHECK (price
> 0),
622 discounted_price numeric CHECK (discounted_price
> 0),
623 <emphasis>CHECK (price
> discounted_price)
</emphasis>
629 The first two constraints should look familiar. The third one
630 uses a new syntax. It is not attached to a particular column,
631 instead it appears as a separate item in the comma-separated
632 column list. Column definitions and these constraint
633 definitions can be listed in mixed order.
637 We say that the first two constraints are column constraints, whereas the
638 third one is a table constraint because it is written separately
639 from any one column definition. Column constraints can also be
640 written as table constraints, while the reverse is not necessarily
641 possible, since a column constraint is supposed to refer to only the
642 column it is attached to. (
<productname>PostgreSQL
</productname> doesn't
643 enforce that rule, but you should follow it if you want your table
644 definitions to work with other database systems.) The above example could
647 CREATE TABLE products (
651 CHECK (price
> 0),
652 discounted_price numeric,
653 CHECK (discounted_price
> 0),
654 CHECK (price
> discounted_price)
659 CREATE TABLE products (
662 price numeric CHECK (price
> 0),
663 discounted_price numeric,
664 CHECK (discounted_price
> 0 AND price
> discounted_price)
667 It's a matter of taste.
671 Names can be assigned to table constraints in the same way as
674 CREATE TABLE products (
678 CHECK (price
> 0),
679 discounted_price numeric,
680 CHECK (discounted_price
> 0),
681 <emphasis>CONSTRAINT valid_discount
</emphasis> CHECK (price
> discounted_price)
687 <primary>null value
</primary>
688 <secondary sortas=
"check constraints">with check constraints
</secondary>
692 It should be noted that a check constraint is satisfied if the
693 check expression evaluates to true or the null value. Since most
694 expressions will evaluate to the null value if any operand is null,
695 they will not prevent null values in the constrained columns. To
696 ensure that a column does not contain null values, the not-null
697 constraint described in the next section can be used.
702 <productname>PostgreSQL
</productname> does not support
703 <literal>CHECK
</literal> constraints that reference table data other than
704 the new or updated row being checked. While a
<literal>CHECK
</literal>
705 constraint that violates this rule may appear to work in simple
706 tests, it cannot guarantee that the database will not reach a state
707 in which the constraint condition is false (due to subsequent changes
708 of the other row(s) involved). This would cause a database dump and
709 restore to fail. The restore could fail even when the complete
710 database state is consistent with the constraint, due to rows not
711 being loaded in an order that will satisfy the constraint. If
712 possible, use
<literal>UNIQUE
</literal>,
<literal>EXCLUDE
</literal>,
713 or
<literal>FOREIGN KEY
</literal> constraints to express
714 cross-row and cross-table restrictions.
718 If what you desire is a one-time check against other rows at row
719 insertion, rather than a continuously-maintained consistency
720 guarantee, a custom
<link linkend=
"triggers">trigger
</link> can be used
721 to implement that. (This approach avoids the dump/restore problem because
722 <application>pg_dump
</application> does not reinstall triggers until after
723 restoring data, so that the check will not be enforced during a
730 <productname>PostgreSQL
</productname> assumes that
731 <literal>CHECK
</literal> constraints' conditions are immutable, that
732 is, they will always give the same result for the same input row.
733 This assumption is what justifies examining
<literal>CHECK
</literal>
734 constraints only when rows are inserted or updated, and not at other
735 times. (The warning above about not referencing other table data is
736 really a special case of this restriction.)
740 An example of a common way to break this assumption is to reference a
741 user-defined function in a
<literal>CHECK
</literal> expression, and
742 then change the behavior of that
743 function.
<productname>PostgreSQL
</productname> does not disallow
744 that, but it will not notice if there are rows in the table that now
745 violate the
<literal>CHECK
</literal> constraint. That would cause a
746 subsequent database dump and restore to fail.
747 The recommended way to handle such a change is to drop the constraint
748 (using
<command>ALTER TABLE
</command>), adjust the function definition,
749 and re-add the constraint, thereby rechecking it against all table rows.
754 <sect2 id=
"ddl-constraints-not-null">
755 <title>Not-Null Constraints
</title>
758 <primary>not-null constraint
</primary>
762 <primary>constraint
</primary>
763 <secondary>NOT NULL
</secondary>
767 A not-null constraint simply specifies that a column must not
768 assume the null value. A syntax example:
770 CREATE TABLE products (
771 product_no integer
<emphasis>NOT NULL
</emphasis>,
772 name text
<emphasis>NOT NULL
</emphasis>,
776 An explicit constraint name can also be specified, for example:
778 CREATE TABLE products (
779 product_no integer NOT NULL,
780 name text
<emphasis>CONSTRAINT products_name_not_null
</emphasis> NOT NULL,
787 A not-null constraint is usually written as a column constraint. The
788 syntax for writing it as a table constraint is
790 CREATE TABLE products (
794 <emphasis>NOT NULL product_no
</emphasis>,
795 <emphasis>NOT NULL name
</emphasis>
798 But this syntax is not standard and mainly intended for use by
799 <application>pg_dump
</application>.
803 A not-null constraint is functionally equivalent to creating a check
804 constraint
<literal>CHECK (
<replaceable>column_name
</replaceable>
805 IS NOT NULL)
</literal>, but in
806 <productname>PostgreSQL
</productname> creating an explicit
807 not-null constraint is more efficient.
811 Of course, a column can have more than one constraint. Just write
812 the constraints one after another:
814 CREATE TABLE products (
815 product_no integer NOT NULL,
817 price numeric NOT NULL CHECK (price
> 0)
820 The order doesn't matter. It does not necessarily determine in which
821 order the constraints are checked.
825 However, a column can have at most one explicit not-null constraint.
829 The
<literal>NOT NULL
</literal> constraint has an inverse: the
830 <literal>NULL
</literal> constraint. This does not mean that the
831 column must be null, which would surely be useless. Instead, this
832 simply selects the default behavior that the column might be null.
833 The
<literal>NULL
</literal> constraint is not present in the SQL
834 standard and should not be used in portable applications. (It was
835 only added to
<productname>PostgreSQL
</productname> to be
836 compatible with some other database systems.) Some users, however,
837 like it because it makes it easy to toggle the constraint in a
838 script file. For example, you could start with:
840 CREATE TABLE products (
841 product_no integer NULL,
846 and then insert the
<literal>NOT
</literal> key word where desired.
851 In most database designs the majority of columns should be marked
857 <sect2 id=
"ddl-constraints-unique-constraints">
858 <title>Unique Constraints
</title>
861 <primary>unique constraint
</primary>
865 <primary>constraint
</primary>
866 <secondary>unique
</secondary>
870 Unique constraints ensure that the data contained in a column, or a
871 group of columns, is unique among all the rows in the
872 table. The syntax is:
874 CREATE TABLE products (
875 product_no integer
<emphasis>UNIQUE
</emphasis>,
880 when written as a column constraint, and:
882 CREATE TABLE products (
886 <emphasis>UNIQUE (product_no)
</emphasis>
889 when written as a table constraint.
893 To define a unique constraint for a group of columns, write it as a
894 table constraint with the column names separated by commas:
896 CREATE TABLE example (
900 <emphasis>UNIQUE (a, c)
</emphasis>
903 This specifies that the combination of values in the indicated columns
904 is unique across the whole table, though any one of the columns
905 need not be (and ordinarily isn't) unique.
909 You can assign your own name for a unique constraint, in the usual way:
911 CREATE TABLE products (
912 product_no integer
<emphasis>CONSTRAINT must_be_different
</emphasis> UNIQUE,
920 Adding a unique constraint will automatically create a unique B-tree
921 index on the column or group of columns listed in the constraint.
922 A uniqueness restriction covering only some rows cannot be written as
923 a unique constraint, but it is possible to enforce such a restriction by
924 creating a unique
<link linkend=
"indexes-partial">partial index
</link>.
928 <primary>null value
</primary>
929 <secondary sortas=
"unique constraints">with unique constraints
</secondary>
933 In general, a unique constraint is violated if there is more than
934 one row in the table where the values of all of the
935 columns included in the constraint are equal.
936 By default, two null values are not considered equal in this
937 comparison. That means even in the presence of a
938 unique constraint it is possible to store duplicate
939 rows that contain a null value in at least one of the constrained
940 columns. This behavior can be changed by adding the clause
<literal>NULLS
941 NOT DISTINCT
</literal>, like
943 CREATE TABLE products (
944 product_no integer UNIQUE
<emphasis>NULLS NOT DISTINCT
</emphasis>,
951 CREATE TABLE products (
955 UNIQUE
<emphasis>NULLS NOT DISTINCT
</emphasis> (product_no)
958 The default behavior can be specified explicitly using
<literal>NULLS
959 DISTINCT
</literal>. The default null treatment in unique constraints is
960 implementation-defined according to the SQL standard, and other
961 implementations have a different behavior. So be careful when developing
962 applications that are intended to be portable.
966 <sect2 id=
"ddl-constraints-primary-keys">
967 <title>Primary Keys
</title>
970 <primary>primary key
</primary>
974 <primary>constraint
</primary>
975 <secondary>primary key
</secondary>
979 A primary key constraint indicates that a column, or group of columns,
980 can be used as a unique identifier for rows in the table. This
981 requires that the values be both unique and not null. So, the following
982 two table definitions accept the same data:
984 CREATE TABLE products (
985 product_no integer UNIQUE NOT NULL,
992 CREATE TABLE products (
993 product_no integer
<emphasis>PRIMARY KEY
</emphasis>,
1001 Primary keys can span more than one column; the syntax
1002 is similar to unique constraints:
1004 CREATE TABLE example (
1008 <emphasis>PRIMARY KEY (a, c)
</emphasis>
1014 Adding a primary key will automatically create a unique B-tree index
1015 on the column or group of columns listed in the primary key, and will
1016 force the column(s) to be marked
<literal>NOT NULL
</literal>.
1020 A table can have at most one primary key. (There can be any number
1021 of unique constraints, which combined with not-null constraints are functionally almost the
1022 same thing, but only one can be identified as the primary key.)
1023 Relational database theory
1024 dictates that every table must have a primary key. This rule is
1025 not enforced by
<productname>PostgreSQL
</productname>, but it is
1026 usually best to follow it.
1030 Primary keys are useful both for
1031 documentation purposes and for client applications. For example,
1032 a GUI application that allows modifying row values probably needs
1033 to know the primary key of a table to be able to identify rows
1034 uniquely. There are also various ways in which the database system
1035 makes use of a primary key if one has been declared; for example,
1036 the primary key defines the default target column(s) for foreign keys
1037 referencing its table.
1041 <sect2 id=
"ddl-constraints-fk">
1042 <title>Foreign Keys
</title>
1045 <primary>foreign key
</primary>
1049 <primary>constraint
</primary>
1050 <secondary>foreign key
</secondary>
1054 <primary>referential integrity
</primary>
1058 A foreign key constraint specifies that the values in a column (or
1059 a group of columns) must match the values appearing in some row
1061 We say this maintains the
<firstterm>referential
1062 integrity
</firstterm> between two related tables.
1066 Say you have the product table that we have used several times already:
1068 CREATE TABLE products (
1069 product_no integer PRIMARY KEY,
1074 Let's also assume you have a table storing orders of those
1075 products. We want to ensure that the orders table only contains
1076 orders of products that actually exist. So we define a foreign
1077 key constraint in the orders table that references the products
1080 CREATE TABLE orders (
1081 order_id integer PRIMARY KEY,
1082 product_no integer
<emphasis>REFERENCES products (product_no)
</emphasis>,
1086 Now it is impossible to create orders with non-NULL
1087 <structfield>product_no
</structfield> entries that do not appear in the
1092 We say that in this situation the orders table is the
1093 <firstterm>referencing
</firstterm> table and the products table is
1094 the
<firstterm>referenced
</firstterm> table. Similarly, there are
1095 referencing and referenced columns.
1099 You can also shorten the above command to:
1101 CREATE TABLE orders (
1102 order_id integer PRIMARY KEY,
1103 product_no integer
<emphasis>REFERENCES products
</emphasis>,
1107 because in absence of a column list the primary key of the
1108 referenced table is used as the referenced column(s).
1112 You can assign your own name for a foreign key constraint,
1117 A foreign key can also constrain and reference a group of columns.
1118 As usual, it then needs to be written in table constraint form.
1119 Here is a contrived syntax example:
1122 a integer PRIMARY KEY,
1125 <emphasis>FOREIGN KEY (b, c) REFERENCES other_table (c1, c2)
</emphasis>
1128 Of course, the number and type of the constrained columns need to
1129 match the number and type of the referenced columns.
1133 <primary>foreign key
</primary>
1134 <secondary>self-referential
</secondary>
1138 Sometimes it is useful for the
<quote>other table
</quote> of a
1139 foreign key constraint to be the same table; this is called
1140 a
<firstterm>self-referential
</firstterm> foreign key. For
1141 example, if you want rows of a table to represent nodes of a tree
1142 structure, you could write
1145 node_id integer PRIMARY KEY,
1146 parent_id integer REFERENCES tree,
1151 A top-level node would have NULL
<structfield>parent_id
</structfield>,
1152 while non-NULL
<structfield>parent_id
</structfield> entries would be
1153 constrained to reference valid rows of the table.
1157 A table can have more than one foreign key constraint. This is
1158 used to implement many-to-many relationships between tables. Say
1159 you have tables about products and orders, but now you want to
1160 allow one order to contain possibly many products (which the
1161 structure above did not allow). You could use this table structure:
1163 CREATE TABLE products (
1164 product_no integer PRIMARY KEY,
1169 CREATE TABLE orders (
1170 order_id integer PRIMARY KEY,
1171 shipping_address text,
1175 CREATE TABLE order_items (
1176 product_no integer REFERENCES products,
1177 order_id integer REFERENCES orders,
1179 PRIMARY KEY (product_no, order_id)
1182 Notice that the primary key overlaps with the foreign keys in
1187 <primary>CASCADE
</primary>
1188 <secondary>foreign key action
</secondary>
1192 <primary>RESTRICT
</primary>
1193 <secondary>foreign key action
</secondary>
1197 We know that the foreign keys disallow creation of orders that
1198 do not relate to any products. But what if a product is removed
1199 after an order is created that references it? SQL allows you to
1200 handle that as well. Intuitively, we have a few options:
1201 <itemizedlist spacing=
"compact">
1202 <listitem><para>Disallow deleting a referenced product
</para></listitem>
1203 <listitem><para>Delete the orders as well
</para></listitem>
1204 <listitem><para>Something else?
</para></listitem>
1209 To illustrate this, let's implement the following policy on the
1210 many-to-many relationship example above: when someone wants to
1211 remove a product that is still referenced by an order (via
1212 <literal>order_items
</literal>), we disallow it. If someone
1213 removes an order, the order items are removed as well:
1215 CREATE TABLE products (
1216 product_no integer PRIMARY KEY,
1221 CREATE TABLE orders (
1222 order_id integer PRIMARY KEY,
1223 shipping_address text,
1227 CREATE TABLE order_items (
1228 product_no integer REFERENCES products
<emphasis>ON DELETE RESTRICT
</emphasis>,
1229 order_id integer REFERENCES orders
<emphasis>ON DELETE CASCADE
</emphasis>,
1231 PRIMARY KEY (product_no, order_id)
1237 The default
<literal>ON DELETE
</literal> action is
<literal>ON DELETE NO
1238 ACTION
</literal>; this does not need to be specified. This means that the
1239 deletion in the referenced table is allowed to proceed. But the
1240 foreign-key constraint is still required to be satisfied, so this
1241 operation will usually result in an error. But checking of foreign-key
1242 constraints can also be deferred to later in the transaction (not covered
1243 in this chapter). In that case, the
<literal>NO ACTION
</literal> setting
1244 would allow other commands to
<quote>fix
</quote> the situation before the
1245 constraint is checked, for example by inserting another suitable row into
1246 the referenced table or by deleting the now-dangling rows from the
1251 <literal>RESTRICT
</literal> is a stricter setting than
<literal>NO
1252 ACTION
</literal>. It prevents deletion of a referenced row.
1253 <literal>RESTRICT
</literal> does not allow the check to be deferred until
1254 later in the transaction.
1258 <literal>CASCADE
</literal> specifies that when a referenced row is deleted,
1259 row(s) referencing it should be automatically deleted as well.
1263 There are two other options:
1264 <literal>SET NULL
</literal> and
<literal>SET DEFAULT
</literal>.
1265 These cause the referencing column(s) in the referencing row(s)
1266 to be set to nulls or their default
1267 values, respectively, when the referenced row is deleted.
1268 Note that these do not excuse you from observing any constraints.
1269 For example, if an action specifies
<literal>SET DEFAULT
</literal>
1270 but the default value would not satisfy the foreign key constraint, the
1271 operation will fail.
1275 The appropriate choice of
<literal>ON DELETE
</literal> action depends on
1276 what kinds of objects the related tables represent. When the referencing
1277 table represents something that is a component of what is represented by
1278 the referenced table and cannot exist independently, then
1279 <literal>CASCADE
</literal> could be appropriate. If the two tables
1280 represent independent objects, then
<literal>RESTRICT
</literal> or
1281 <literal>NO ACTION
</literal> is more appropriate; an application that
1282 actually wants to delete both objects would then have to be explicit about
1283 this and run two delete commands. In the above example, order items are
1284 part of an order, and it is convenient if they are deleted automatically
1285 if an order is deleted. But products and orders are different things, and
1286 so making a deletion of a product automatically cause the deletion of some
1287 order items could be considered problematic. The actions
<literal>SET
1288 NULL
</literal> or
<literal>SET DEFAULT
</literal> can be appropriate if a
1289 foreign-key relationship represents optional information. For example, if
1290 the products table contained a reference to a product manager, and the
1291 product manager entry gets deleted, then setting the product's product
1292 manager to null or a default might be useful.
1296 The actions
<literal>SET NULL
</literal> and
<literal>SET DEFAULT
</literal>
1297 can take a column list to specify which columns to set. Normally, all
1298 columns of the foreign-key constraint are set; setting only a subset is
1299 useful in some special cases. Consider the following example:
1301 CREATE TABLE tenants (
1302 tenant_id integer PRIMARY KEY
1305 CREATE TABLE users (
1306 tenant_id integer REFERENCES tenants ON DELETE CASCADE,
1307 user_id integer NOT NULL,
1308 PRIMARY KEY (tenant_id, user_id)
1311 CREATE TABLE posts (
1312 tenant_id integer REFERENCES tenants ON DELETE CASCADE,
1313 post_id integer NOT NULL,
1315 PRIMARY KEY (tenant_id, post_id),
1316 FOREIGN KEY (tenant_id, author_id) REFERENCES users ON DELETE SET NULL
<emphasis>(author_id)
</emphasis>
1319 Without the specification of the column, the foreign key would also set
1320 the column
<literal>tenant_id
</literal> to null, but that column is still
1321 required as part of the primary key.
1325 Analogous to
<literal>ON DELETE
</literal> there is also
1326 <literal>ON UPDATE
</literal> which is invoked when a referenced
1327 column is changed (updated). The possible actions are the same,
1328 except that column lists cannot be specified for
<literal>SET
1329 NULL
</literal> and
<literal>SET DEFAULT
</literal>.
1330 In this case,
<literal>CASCADE
</literal> means that the updated values of the
1331 referenced column(s) should be copied into the referencing row(s).
1332 There is also a noticeable difference between
<literal>ON UPDATE NO
1333 ACTION
</literal> (the default) and
<literal>ON UPDATE RESTRICT
</literal>.
1334 The former will allow the update to proceed and the foreign-key constraint
1335 will be checked against the state after the update. The latter will
1336 prevent the update to run even if the state after the update would still
1337 satisfy the constraint. This prevents updating a referenced row to a
1338 value that is distinct but compares as equal (for example, a character
1339 string with a different case variant, if a character string type with a
1340 case-insensitive collation is used).
1344 Normally, a referencing row need not satisfy the foreign key constraint
1345 if any of its referencing columns are null. If
<literal>MATCH FULL
</literal>
1346 is added to the foreign key declaration, a referencing row escapes
1347 satisfying the constraint only if all its referencing columns are null
1348 (so a mix of null and non-null values is guaranteed to fail a
1349 <literal>MATCH FULL
</literal> constraint). If you don't want referencing rows
1350 to be able to avoid satisfying the foreign key constraint, declare the
1351 referencing column(s) as
<literal>NOT NULL
</literal>.
1355 A foreign key must reference columns that either are a primary key or
1356 form a unique constraint, or are columns from a non-partial unique index.
1357 This means that the referenced columns always have an index to allow
1358 efficient lookups on whether a referencing row has a match. Since a
1359 <command>DELETE
</command> of a row from the referenced table or an
1360 <command>UPDATE
</command> of a referenced column will require a scan of
1361 the referencing table for rows matching the old value, it is often a good
1362 idea to index the referencing columns too. Because this is not always
1363 needed, and there are many choices available on how to index, the
1364 declaration of a foreign key constraint does not automatically create an
1365 index on the referencing columns.
1369 More information about updating and deleting data is in
<xref
1370 linkend=
"dml"/>. Also see the description of foreign key constraint
1371 syntax in the reference documentation for
1372 <xref linkend=
"sql-createtable"/>.
1376 <sect2 id=
"ddl-constraints-exclusion">
1377 <title>Exclusion Constraints
</title>
1380 <primary>exclusion constraint
</primary>
1384 <primary>constraint
</primary>
1385 <secondary>exclusion
</secondary>
1389 Exclusion constraints ensure that if any two rows are compared on
1390 the specified columns or expressions using the specified operators,
1391 at least one of these operator comparisons will return false or null.
1394 CREATE TABLE circles (
1396 EXCLUDE USING gist (c WITH
&&)
1402 See also
<link linkend=
"sql-createtable-exclude"><command>CREATE
1403 TABLE ... CONSTRAINT ... EXCLUDE
</command></link> for details.
1407 Adding an exclusion constraint will automatically create an index
1408 of the type specified in the constraint declaration.
1413 <sect1 id=
"ddl-system-columns">
1414 <title>System Columns
</title>
1417 Every table has several
<firstterm>system columns
</firstterm> that are
1418 implicitly defined by the system. Therefore, these names cannot be
1419 used as names of user-defined columns. (Note that these
1420 restrictions are separate from whether the name is a key word or
1421 not; quoting a name will not allow you to escape these
1422 restrictions.) You do not really need to be concerned about these
1423 columns; just know they exist.
1427 <primary>column
</primary>
1428 <secondary>system column
</secondary>
1432 <varlistentry id=
"ddl-system-columns-tableoid">
1433 <term><structfield>tableoid
</structfield></term>
1436 <primary>tableoid
</primary>
1440 The OID of the table containing this row. This column is
1441 particularly handy for queries that select from partitioned
1442 tables (see
<xref linkend=
"ddl-partitioning"/>) or inheritance
1443 hierarchies (see
<xref linkend=
"ddl-inherit"/>), since without it,
1444 it's difficult to tell which individual table a row came from. The
1445 <structfield>tableoid
</structfield> can be joined against the
1446 <structfield>oid
</structfield> column of
1447 <structname>pg_class
</structname> to obtain the table name.
1452 <varlistentry id=
"ddl-system-columns-xmin">
1453 <term><structfield>xmin
</structfield></term>
1456 <primary>xmin
</primary>
1460 The identity (transaction ID) of the inserting transaction for
1461 this row version. (A row version is an individual state of a
1462 row; each update of a row creates a new row version for the same
1468 <varlistentry id=
"ddl-system-columns-cmin">
1469 <term><structfield>cmin
</structfield></term>
1472 <primary>cmin
</primary>
1476 The command identifier (starting at zero) within the inserting
1482 <varlistentry id=
"ddl-system-columns-xmax">
1483 <term><structfield>xmax
</structfield></term>
1486 <primary>xmax
</primary>
1490 The identity (transaction ID) of the deleting transaction, or
1491 zero for an undeleted row version. It is possible for this column to
1492 be nonzero in a visible row version. That usually indicates that the
1493 deleting transaction hasn't committed yet, or that an attempted
1494 deletion was rolled back.
1499 <varlistentry id=
"ddl-system-columns-cmax">
1500 <term><structfield>cmax
</structfield></term>
1503 <primary>cmax
</primary>
1507 The command identifier within the deleting transaction, or zero.
1512 <varlistentry id=
"ddl-system-columns-ctid">
1513 <term><structfield>ctid
</structfield></term>
1516 <primary>ctid
</primary>
1520 The physical location of the row version within its table. Note that
1521 although the
<structfield>ctid
</structfield> can be used to
1522 locate the row version very quickly, a row's
1523 <structfield>ctid
</structfield> will change if it is
1524 updated or moved by
<command>VACUUM FULL
</command>. Therefore
1525 <structfield>ctid
</structfield> is useless as a long-term row
1526 identifier. A primary key should be used to identify logical rows.
1533 Transaction identifiers are also
32-bit quantities. In a
1534 long-lived database it is possible for transaction IDs to wrap
1535 around. This is not a fatal problem given appropriate maintenance
1536 procedures; see
<xref linkend=
"maintenance"/> for details. It is
1537 unwise, however, to depend on the uniqueness of transaction IDs
1538 over the long term (more than one billion transactions).
1542 Command identifiers are also
32-bit quantities. This creates a hard limit
1543 of
2<superscript>32</superscript> (
4 billion)
<acronym>SQL
</acronym> commands
1544 within a single transaction. In practice this limit is not a
1545 problem
— note that the limit is on the number of
1546 <acronym>SQL
</acronym> commands, not the number of rows processed.
1547 Also, only commands that actually modify the database contents will
1548 consume a command identifier.
1552 <sect1 id=
"ddl-alter">
1553 <title>Modifying Tables
</title>
1555 <indexterm zone=
"ddl-alter">
1556 <primary>table
</primary>
1557 <secondary>modifying
</secondary>
1561 When you create a table and you realize that you made a mistake, or
1562 the requirements of the application change, you can drop the
1563 table and create it again. But this is not a convenient option if
1564 the table is already filled with data, or if the table is
1565 referenced by other database objects (for instance a foreign key
1566 constraint). Therefore
<productname>PostgreSQL
</productname>
1567 provides a family of commands to make modifications to existing
1568 tables. Note that this is conceptually distinct from altering
1569 the data contained in the table: here we are interested in altering
1570 the definition, or structure, of the table.
1575 <itemizedlist spacing=
"compact">
1577 <para>Add columns
</para>
1580 <para>Remove columns
</para>
1583 <para>Add constraints
</para>
1586 <para>Remove constraints
</para>
1589 <para>Change default values
</para>
1592 <para>Change column data types
</para>
1595 <para>Rename columns
</para>
1598 <para>Rename tables
</para>
1602 All these actions are performed using the
1603 <xref linkend=
"sql-altertable"/>
1604 command, whose reference page contains details beyond those given
1608 <sect2 id=
"ddl-alter-adding-a-column">
1609 <title>Adding a Column
</title>
1612 <primary>column
</primary>
1613 <secondary>adding
</secondary>
1617 To add a column, use a command like:
1619 ALTER TABLE products ADD COLUMN description text;
1621 The new column is initially filled with whatever default
1622 value is given (null if you don't specify a
<literal>DEFAULT
</literal> clause).
1627 From
<productname>PostgreSQL
</productname> 11, adding a column with
1628 a constant default value no longer means that each row of the table
1629 needs to be updated when the
<command>ALTER TABLE
</command> statement
1630 is executed. Instead, the default value will be returned the next time
1631 the row is accessed, and applied when the table is rewritten, making
1632 the
<command>ALTER TABLE
</command> very fast even on large tables.
1636 However, if the default value is volatile (e.g.,
1637 <function>clock_timestamp()
</function>)
1638 each row will need to be updated with the value calculated at the time
1639 <command>ALTER TABLE
</command> is executed. To avoid a potentially
1640 lengthy update operation, particularly if you intend to fill the column
1641 with mostly nondefault values anyway, it may be preferable to add the
1642 column with no default, insert the correct values using
1643 <command>UPDATE
</command>, and then add any desired default as described
1649 You can also define constraints on the column at the same time,
1650 using the usual syntax:
1652 ALTER TABLE products ADD COLUMN description text CHECK (description
<> '');
1654 In fact all the options that can be applied to a column description
1655 in
<command>CREATE TABLE
</command> can be used here. Keep in mind however
1656 that the default value must satisfy the given constraints, or the
1657 <literal>ADD
</literal> will fail. Alternatively, you can add
1658 constraints later (see below) after you've filled in the new column
1664 <sect2 id=
"ddl-alter-removing-a-column">
1665 <title>Removing a Column
</title>
1668 <primary>column
</primary>
1669 <secondary>removing
</secondary>
1673 To remove a column, use a command like:
1675 ALTER TABLE products DROP COLUMN description;
1677 Whatever data was in the column disappears. Table constraints involving
1678 the column are dropped, too. However, if the column is referenced by a
1679 foreign key constraint of another table,
1680 <productname>PostgreSQL
</productname> will not silently drop that
1681 constraint. You can authorize dropping everything that depends on
1682 the column by adding
<literal>CASCADE
</literal>:
1684 ALTER TABLE products DROP COLUMN description CASCADE;
1686 See
<xref linkend=
"ddl-depend"/> for a description of the general
1687 mechanism behind this.
1691 <sect2 id=
"ddl-alter-adding-a-constraint">
1692 <title>Adding a Constraint
</title>
1695 <primary>constraint
</primary>
1696 <secondary>adding
</secondary>
1700 To add a constraint, the table constraint syntax is used. For example:
1702 ALTER TABLE products ADD CHECK (name
<> '');
1703 ALTER TABLE products ADD CONSTRAINT some_name UNIQUE (product_no);
1704 ALTER TABLE products ADD FOREIGN KEY (product_group_id) REFERENCES product_groups;
1709 To add a not-null constraint, which is normally not written as a table
1710 constraint, this special syntax is available:
1712 ALTER TABLE products ALTER COLUMN product_no SET NOT NULL;
1714 This command silently does nothing if the column already has a
1715 not-null constraint.
1719 The constraint will be checked immediately, so the table data must
1720 satisfy the constraint before it can be added.
1724 <sect2 id=
"ddl-alter-removing-a-constraint">
1725 <title>Removing a Constraint
</title>
1728 <primary>constraint
</primary>
1729 <secondary>removing
</secondary>
1733 To remove a constraint you need to know its name. If you gave it
1734 a name then that's easy. Otherwise the system assigned a
1735 generated name, which you need to find out. The
1736 <application>psql
</application> command
<literal>\d
1737 <replaceable>tablename
</replaceable></literal> can be helpful
1738 here; other interfaces might also provide a way to inspect table
1739 details. Then the command is:
1741 ALTER TABLE products DROP CONSTRAINT some_name;
1743 (If you are dealing with a generated constraint name like
<literal>$
2</literal>,
1744 don't forget that you'll need to double-quote it to make it a valid
1749 As with dropping a column, you need to add
<literal>CASCADE
</literal> if you
1750 want to drop a constraint that something else depends on. An example
1751 is that a foreign key constraint depends on a unique or primary key
1752 constraint on the referenced column(s).
1756 Simplified syntax is available to drop a not-null constraint:
1758 ALTER TABLE products ALTER COLUMN product_no DROP NOT NULL;
1760 This mirrors the
<literal>SET NOT NULL
</literal> syntax for adding a
1761 not-null constraint. This command will silently do nothing if the column
1762 does not have a not-null constraint. (Recall that a column can have at
1763 most one not-null constraint, so it is never ambiguous which constraint
1764 this command acts on.)
1768 <sect2 id=
"ddl-alter-column-default">
1769 <title>Changing a Column's Default Value
</title>
1772 <primary>default value
</primary>
1773 <secondary>changing
</secondary>
1777 To set a new default for a column, use a command like:
1779 ALTER TABLE products ALTER COLUMN price SET DEFAULT
7.77;
1781 Note that this doesn't affect any existing rows in the table, it
1782 just changes the default for future
<command>INSERT
</command> commands.
1786 To remove any default value, use:
1788 ALTER TABLE products ALTER COLUMN price DROP DEFAULT;
1790 This is effectively the same as setting the default to null.
1791 As a consequence, it is not an error
1792 to drop a default where one hadn't been defined, because the
1793 default is implicitly the null value.
1797 <sect2 id=
"ddl-alter-column-type">
1798 <title>Changing a Column's Data Type
</title>
1801 <primary>column data type
</primary>
1802 <secondary>changing
</secondary>
1806 To convert a column to a different data type, use a command like:
1808 ALTER TABLE products ALTER COLUMN price TYPE numeric(
10,
2);
1810 This will succeed only if each existing entry in the column can be
1811 converted to the new type by an implicit cast. If a more complex
1812 conversion is needed, you can add a
<literal>USING
</literal> clause that
1813 specifies how to compute the new values from the old.
1817 <productname>PostgreSQL
</productname> will attempt to convert the column's
1818 default value (if any) to the new type, as well as any constraints
1819 that involve the column. But these conversions might fail, or might
1820 produce surprising results. It's often best to drop any constraints
1821 on the column before altering its type, and then add back suitably
1822 modified constraints afterwards.
1826 <sect2 id=
"ddl-alter-renaming-column">
1827 <title>Renaming a Column
</title>
1830 <primary>column
</primary>
1831 <secondary>renaming
</secondary>
1837 ALTER TABLE products RENAME COLUMN product_no TO product_number;
1842 <sect2 id=
"ddl-alter-renaming-table">
1843 <title>Renaming a Table
</title>
1846 <primary>table
</primary>
1847 <secondary>renaming
</secondary>
1853 ALTER TABLE products RENAME TO items;
1859 <sect1 id=
"ddl-priv">
1860 <title>Privileges
</title>
1862 <indexterm zone=
"ddl-priv">
1863 <primary>privilege
</primary>
1867 <primary>permission
</primary>
1868 <see>privilege
</see>
1871 <indexterm zone=
"ddl-priv">
1872 <primary>owner
</primary>
1875 <indexterm zone=
"ddl-priv">
1876 <primary>GRANT
</primary>
1879 <indexterm zone=
"ddl-priv">
1880 <primary>REVOKE
</primary>
1883 <indexterm zone=
"ddl-priv">
1884 <primary><acronym>ACL
</acronym></primary>
1887 <indexterm zone=
"ddl-priv-default">
1888 <primary>privilege
</primary>
1889 <secondary>default
</secondary>
1893 When an object is created, it is assigned an owner. The
1894 owner is normally the role that executed the creation statement.
1895 For most kinds of objects, the initial state is that only the owner
1896 (or a superuser) can do anything with the object. To allow
1897 other roles to use it,
<firstterm>privileges
</firstterm> must be
1902 There are different kinds of privileges:
<literal>SELECT
</literal>,
1903 <literal>INSERT
</literal>,
<literal>UPDATE
</literal>,
<literal>DELETE
</literal>,
1904 <literal>TRUNCATE
</literal>,
<literal>REFERENCES
</literal>,
<literal>TRIGGER
</literal>,
1905 <literal>CREATE
</literal>,
<literal>CONNECT
</literal>,
<literal>TEMPORARY
</literal>,
1906 <literal>EXECUTE
</literal>,
<literal>USAGE
</literal>,
<literal>SET
</literal>,
1907 <literal>ALTER SYSTEM
</literal>, and
<literal>MAINTAIN
</literal>.
1908 The privileges applicable to a particular
1909 object vary depending on the object's type (table, function, etc.).
1910 More detail about the meanings of these privileges appears below.
1911 The following sections and chapters will also show you how
1912 these privileges are used.
1916 The right to modify or destroy an object is inherent in being the
1917 object's owner, and cannot be granted or revoked in itself.
1918 (However, like all privileges, that right can be inherited by
1919 members of the owning role; see
<xref linkend=
"role-membership"/>.)
1923 An object can be assigned to a new owner with an
<command>ALTER
</command>
1924 command of the appropriate kind for the object, for example
1926 ALTER TABLE
<replaceable>table_name
</replaceable> OWNER TO
<replaceable>new_owner
</replaceable>;
1928 Superusers can always do this; ordinary roles can only do it if they are
1929 both the current owner of the object (or inherit the privileges of the
1930 owning role) and able to
<literal>SET ROLE
</literal> to the new owning role.
1934 To assign privileges, the
<xref linkend=
"sql-grant"/> command is
1935 used. For example, if
<literal>joe
</literal> is an existing role, and
1936 <literal>accounts
</literal> is an existing table, the privilege to
1937 update the table can be granted with:
1939 GRANT UPDATE ON accounts TO joe;
1941 Writing
<literal>ALL
</literal> in place of a specific privilege grants all
1942 privileges that are relevant for the object type.
1946 The special
<quote>role
</quote> name
<literal>PUBLIC
</literal> can
1947 be used to grant a privilege to every role on the system. Also,
1948 <quote>group
</quote> roles can be set up to help manage privileges when
1949 there are many users of a database
— for details see
1950 <xref linkend=
"user-manag"/>.
1954 To revoke a previously-granted privilege, use the fittingly named
1955 <xref linkend=
"sql-revoke"/> command:
1957 REVOKE ALL ON accounts FROM PUBLIC;
1962 Ordinarily, only the object's owner (or a superuser) can grant or
1963 revoke privileges on an object. However, it is possible to grant a
1964 privilege
<quote>with grant option
</quote>, which gives the recipient
1965 the right to grant it in turn to others. If the grant option is
1966 subsequently revoked then all who received the privilege from that
1967 recipient (directly or through a chain of grants) will lose the
1968 privilege. For details see the
<xref linkend=
"sql-grant"/> and
1969 <xref linkend=
"sql-revoke"/> reference pages.
1973 An object's owner can choose to revoke their own ordinary privileges,
1974 for example to make a table read-only for themselves as well as others.
1975 But owners are always treated as holding all grant options, so they
1976 can always re-grant their own privileges.
1980 The available privileges are:
1983 <varlistentry id=
"ddl-priv-select">
1984 <term><literal>SELECT
</literal></term>
1987 Allows
<command>SELECT
</command> from
1988 any column, or specific column(s), of a table, view, materialized
1989 view, or other table-like object.
1990 Also allows use of
<command>COPY TO
</command>.
1991 This privilege is also needed to reference existing column values in
1992 <command>UPDATE
</command>,
<command>DELETE
</command>,
1993 or
<command>MERGE
</command>.
1994 For sequences, this privilege also allows use of the
1995 <function>currval
</function> function.
1996 For large objects, this privilege allows the object to be read.
2001 <varlistentry id=
"ddl-priv-insert">
2002 <term><literal>INSERT
</literal></term>
2005 Allows
<command>INSERT
</command> of a new row into a table, view,
2006 etc. Can be granted on specific column(s), in which case
2007 only those columns may be assigned to in the
<command>INSERT
</command>
2008 command (other columns will therefore receive default values).
2009 Also allows use of
<command>COPY FROM
</command>.
2014 <varlistentry id=
"ddl-priv-update">
2015 <term><literal>UPDATE
</literal></term>
2018 Allows
<command>UPDATE
</command> of any
2019 column, or specific column(s), of a table, view, etc.
2020 (In practice, any nontrivial
<command>UPDATE
</command> command will
2021 require
<literal>SELECT
</literal> privilege as well, since it must
2022 reference table columns to determine which rows to update, and/or to
2023 compute new values for columns.)
2024 <literal>SELECT ... FOR UPDATE
</literal>
2025 and
<literal>SELECT ... FOR SHARE
</literal>
2026 also require this privilege on at least one column, in addition to the
2027 <literal>SELECT
</literal> privilege. For sequences, this
2028 privilege allows use of the
<function>nextval
</function> and
2029 <function>setval
</function> functions.
2030 For large objects, this privilege allows writing or truncating the
2036 <varlistentry id=
"ddl-priv-delete">
2037 <term><literal>DELETE
</literal></term>
2040 Allows
<command>DELETE
</command> of a row from a table, view, etc.
2041 (In practice, any nontrivial
<command>DELETE
</command> command will
2042 require
<literal>SELECT
</literal> privilege as well, since it must
2043 reference table columns to determine which rows to delete.)
2048 <varlistentry id=
"ddl-priv-truncate">
2049 <term><literal>TRUNCATE
</literal></term>
2052 Allows
<command>TRUNCATE
</command> on a table.
2057 <varlistentry id=
"ddl-priv-references">
2058 <term><literal>REFERENCES
</literal></term>
2061 Allows creation of a foreign key constraint referencing a
2062 table, or specific column(s) of a table.
2067 <varlistentry id=
"ddl-priv-trigger">
2068 <term><literal>TRIGGER
</literal></term>
2071 Allows creation of a trigger on a table, view, etc.
2076 <varlistentry id=
"ddl-priv-create">
2077 <term><literal>CREATE
</literal></term>
2080 For databases, allows new schemas and publications to be created within
2081 the database, and allows trusted extensions to be installed within
2085 For schemas, allows new objects to be created within the schema.
2086 To rename an existing object, you must own the
2087 object
<emphasis>and
</emphasis> have this privilege for the containing
2091 For tablespaces, allows tables, indexes, and temporary files to be
2092 created within the tablespace, and allows databases to be created that
2093 have the tablespace as their default tablespace.
2096 Note that revoking this privilege will not alter the existence or
2097 location of existing objects.
2102 <varlistentry id=
"ddl-priv-connect">
2103 <term><literal>CONNECT
</literal></term>
2106 Allows the grantee to connect to the database. This
2107 privilege is checked at connection startup (in addition to checking
2108 any restrictions imposed by
<filename>pg_hba.conf
</filename>).
2113 <varlistentry id=
"ddl-priv-temporary">
2114 <term><literal>TEMPORARY
</literal></term>
2117 Allows temporary tables to be created while using the database.
2122 <varlistentry id=
"ddl-priv-execute">
2123 <term><literal>EXECUTE
</literal></term>
2126 Allows calling a function or procedure, including use of
2127 any operators that are implemented on top of the function. This is the
2128 only type of privilege that is applicable to functions and procedures.
2133 <varlistentry id=
"ddl-priv-usage">
2134 <term><literal>USAGE
</literal></term>
2137 For procedural languages, allows use of the language for
2138 the creation of functions in that language. This is the only type
2139 of privilege that is applicable to procedural languages.
2142 For schemas, allows access to objects contained in the
2143 schema (assuming that the objects' own privilege requirements are
2144 also met). Essentially this allows the grantee to
<quote>look up
</quote>
2145 objects within the schema. Without this permission, it is still
2146 possible to see the object names, e.g., by querying system catalogs.
2147 Also, after revoking this permission, existing sessions might have
2148 statements that have previously performed this lookup, so this is not
2149 a completely secure way to prevent object access.
2152 For sequences, allows use of the
2153 <function>currval
</function> and
<function>nextval
</function> functions.
2156 For types and domains, allows use of the type or domain in the
2157 creation of tables, functions, and other schema objects. (Note that
2158 this privilege does not control all
<quote>usage
</quote> of the
2159 type, such as values of the type appearing in queries. It only
2160 prevents objects from being created that depend on the type. The
2161 main purpose of this privilege is controlling which users can create
2162 dependencies on a type, which could prevent the owner from changing
2166 For foreign-data wrappers, allows creation of new servers using the
2167 foreign-data wrapper.
2170 For foreign servers, allows creation of foreign tables using the
2171 server. Grantees may also create, alter, or drop their own user
2172 mappings associated with that server.
2177 <varlistentry id=
"ddl-priv-set">
2178 <term><literal>SET
</literal></term>
2181 Allows a server configuration parameter to be set to a new value
2182 within the current session. (While this privilege can be granted
2183 on any parameter, it is meaningless except for parameters that would
2184 normally require superuser privilege to set.)
2189 <varlistentry id=
"ddl-priv-alter-system">
2190 <term><literal>ALTER SYSTEM
</literal></term>
2193 Allows a server configuration parameter to be configured to a new
2194 value using the
<xref linkend=
"sql-altersystem"/> command.
2199 <varlistentry id=
"ddl-priv-maintain">
2200 <term><literal>MAINTAIN
</literal></term>
2203 Allows
<command>VACUUM
</command>,
<command>ANALYZE
</command>,
2204 <command>CLUSTER
</command>,
<command>REFRESH MATERIALIZED VIEW
</command>,
2205 <command>REINDEX
</command>, and
<command>LOCK TABLE
</command> on a
2212 The privileges required by other commands are listed on the
2213 reference page of the respective command.
2216 <para id=
"ddl-priv-default">
2217 PostgreSQL grants privileges on some types of objects to
2218 <literal>PUBLIC
</literal> by default when the objects are created.
2219 No privileges are granted to
<literal>PUBLIC
</literal> by default on
2223 foreign data wrappers,
2228 or configuration parameters.
2229 For other types of objects, the default privileges
2230 granted to
<literal>PUBLIC
</literal> are as follows:
2231 <literal>CONNECT
</literal> and
<literal>TEMPORARY
</literal> (create
2232 temporary tables) privileges for databases;
2233 <literal>EXECUTE
</literal> privilege for functions and procedures; and
2234 <literal>USAGE
</literal> privilege for languages and data types
2235 (including domains).
2236 The object owner can, of course,
<command>REVOKE
</command>
2237 both default and expressly granted privileges. (For maximum
2238 security, issue the
<command>REVOKE
</command> in the same transaction that
2239 creates the object; then there is no window in which another user
2240 can use the object.)
2241 Also, these default privilege settings can be overridden using the
2242 <xref linkend=
"sql-alterdefaultprivileges"/> command.
2246 <xref linkend=
"privilege-abbrevs-table"/> shows the one-letter
2247 abbreviations that are used for these privilege types in
2248 <firstterm><acronym>ACL
</acronym></firstterm> values.
2249 You will see these letters in the output of the
<xref linkend=
"app-psql"/>
2250 commands listed below, or when looking at
<acronym>ACL
</acronym> columns
2254 <table id=
"privilege-abbrevs-table">
2255 <title><acronym>ACL
</acronym> Privilege Abbreviations
</title>
2257 <colspec colname=
"col1" colwidth=
"1*"/>
2258 <colspec colname=
"col2" colwidth=
"1*"/>
2259 <colspec colname=
"col3" colwidth=
"2*"/>
2262 <entry>Privilege
</entry>
2263 <entry>Abbreviation
</entry>
2264 <entry>Applicable Object Types
</entry>
2269 <entry><literal>SELECT
</literal></entry>
2270 <entry><literal>r
</literal> (
<quote>read
</quote>)
</entry>
2272 <literal>LARGE OBJECT
</literal>,
2273 <literal>SEQUENCE
</literal>,
2274 <literal>TABLE
</literal> (and table-like objects),
2279 <entry><literal>INSERT
</literal></entry>
2280 <entry><literal>a
</literal> (
<quote>append
</quote>)
</entry>
2281 <entry><literal>TABLE
</literal>, table column
</entry>
2284 <entry><literal>UPDATE
</literal></entry>
2285 <entry><literal>w
</literal> (
<quote>write
</quote>)
</entry>
2287 <literal>LARGE OBJECT
</literal>,
2288 <literal>SEQUENCE
</literal>,
2289 <literal>TABLE
</literal>,
2294 <entry><literal>DELETE
</literal></entry>
2295 <entry><literal>d
</literal></entry>
2296 <entry><literal>TABLE
</literal></entry>
2299 <entry><literal>TRUNCATE
</literal></entry>
2300 <entry><literal>D
</literal></entry>
2301 <entry><literal>TABLE
</literal></entry>
2304 <entry><literal>REFERENCES
</literal></entry>
2305 <entry><literal>x
</literal></entry>
2306 <entry><literal>TABLE
</literal>, table column
</entry>
2309 <entry><literal>TRIGGER
</literal></entry>
2310 <entry><literal>t
</literal></entry>
2311 <entry><literal>TABLE
</literal></entry>
2314 <entry><literal>CREATE
</literal></entry>
2315 <entry><literal>C
</literal></entry>
2317 <literal>DATABASE
</literal>,
2318 <literal>SCHEMA
</literal>,
2319 <literal>TABLESPACE
</literal>
2323 <entry><literal>CONNECT
</literal></entry>
2324 <entry><literal>c
</literal></entry>
2325 <entry><literal>DATABASE
</literal></entry>
2328 <entry><literal>TEMPORARY
</literal></entry>
2329 <entry><literal>T
</literal></entry>
2330 <entry><literal>DATABASE
</literal></entry>
2333 <entry><literal>EXECUTE
</literal></entry>
2334 <entry><literal>X
</literal></entry>
2335 <entry><literal>FUNCTION
</literal>,
<literal>PROCEDURE
</literal></entry>
2338 <entry><literal>USAGE
</literal></entry>
2339 <entry><literal>U
</literal></entry>
2341 <literal>DOMAIN
</literal>,
2342 <literal>FOREIGN DATA WRAPPER
</literal>,
2343 <literal>FOREIGN SERVER
</literal>,
2344 <literal>LANGUAGE
</literal>,
2345 <literal>SCHEMA
</literal>,
2346 <literal>SEQUENCE
</literal>,
2347 <literal>TYPE
</literal>
2351 <entry><literal>SET
</literal></entry>
2352 <entry><literal>s
</literal></entry>
2353 <entry><literal>PARAMETER
</literal></entry>
2356 <entry><literal>ALTER SYSTEM
</literal></entry>
2357 <entry><literal>A
</literal></entry>
2358 <entry><literal>PARAMETER
</literal></entry>
2361 <entry><literal>MAINTAIN
</literal></entry>
2362 <entry><literal>m
</literal></entry>
2363 <entry><literal>TABLE
</literal></entry>
2370 <xref linkend=
"privileges-summary-table"/> summarizes the privileges
2371 available for each type of SQL object, using the abbreviations shown
2373 It also shows the
<application>psql
</application> command
2374 that can be used to examine privilege settings for each object type.
2377 <table id=
"privileges-summary-table">
2378 <title>Summary of Access Privileges
</title>
2380 <colspec colname=
"col1" colwidth=
"2*"/>
2381 <colspec colname=
"col2" colwidth=
"1*"/>
2382 <colspec colname=
"col3" colwidth=
"1*"/>
2383 <colspec colname=
"col4" colwidth=
"1*"/>
2386 <entry>Object Type
</entry>
2387 <entry>All Privileges
</entry>
2388 <entry>Default
<literal>PUBLIC
</literal> Privileges
</entry>
2389 <entry><application>psql
</application> Command
</entry>
2394 <entry><literal>DATABASE
</literal></entry>
2395 <entry><literal>CTc
</literal></entry>
2396 <entry><literal>Tc
</literal></entry>
2397 <entry><literal>\l
</literal></entry>
2400 <entry><literal>DOMAIN
</literal></entry>
2401 <entry><literal>U
</literal></entry>
2402 <entry><literal>U
</literal></entry>
2403 <entry><literal>\dD+
</literal></entry>
2406 <entry><literal>FUNCTION
</literal> or
<literal>PROCEDURE
</literal></entry>
2407 <entry><literal>X
</literal></entry>
2408 <entry><literal>X
</literal></entry>
2409 <entry><literal>\df+
</literal></entry>
2412 <entry><literal>FOREIGN DATA WRAPPER
</literal></entry>
2413 <entry><literal>U
</literal></entry>
2415 <entry><literal>\dew+
</literal></entry>
2418 <entry><literal>FOREIGN SERVER
</literal></entry>
2419 <entry><literal>U
</literal></entry>
2421 <entry><literal>\des+
</literal></entry>
2424 <entry><literal>LANGUAGE
</literal></entry>
2425 <entry><literal>U
</literal></entry>
2426 <entry><literal>U
</literal></entry>
2427 <entry><literal>\dL+
</literal></entry>
2430 <entry><literal>LARGE OBJECT
</literal></entry>
2431 <entry><literal>rw
</literal></entry>
2433 <entry><literal>\dl+
</literal></entry>
2436 <entry><literal>PARAMETER
</literal></entry>
2437 <entry><literal>sA
</literal></entry>
2439 <entry><literal>\dconfig+
</literal></entry>
2442 <entry><literal>SCHEMA
</literal></entry>
2443 <entry><literal>UC
</literal></entry>
2445 <entry><literal>\dn+
</literal></entry>
2448 <entry><literal>SEQUENCE
</literal></entry>
2449 <entry><literal>rwU
</literal></entry>
2451 <entry><literal>\dp
</literal></entry>
2454 <entry><literal>TABLE
</literal> (and table-like objects)
</entry>
2455 <entry><literal>arwdDxtm
</literal></entry>
2457 <entry><literal>\dp
</literal></entry>
2460 <entry>Table column
</entry>
2461 <entry><literal>arwx
</literal></entry>
2463 <entry><literal>\dp
</literal></entry>
2466 <entry><literal>TABLESPACE
</literal></entry>
2467 <entry><literal>C
</literal></entry>
2469 <entry><literal>\db+
</literal></entry>
2472 <entry><literal>TYPE
</literal></entry>
2473 <entry><literal>U
</literal></entry>
2474 <entry><literal>U
</literal></entry>
2475 <entry><literal>\dT+
</literal></entry>
2483 <primary><type>aclitem
</type></primary>
2485 The privileges that have been granted for a particular object are
2486 displayed as a list of
<type>aclitem
</type> entries, each having the
2489 <replaceable>grantee
</replaceable><literal>=
</literal><replaceable>privilege-abbreviation
</replaceable><optional><literal>*
</literal></optional>...
<literal>/
</literal><replaceable>grantor
</replaceable>
2491 Each
<type>aclitem
</type> lists all the permissions of one grantee that
2492 have been granted by a particular grantor. Specific privileges are
2493 represented by one-letter abbreviations from
2494 <xref linkend=
"privilege-abbrevs-table"/>, with
<literal>*
</literal>
2495 appended if the privilege was granted with grant option. For example,
2496 <literal>calvin=r*w/hobbes
</literal> specifies that the role
2497 <literal>calvin
</literal> has the privilege
2498 <literal>SELECT
</literal> (
<literal>r
</literal>) with grant option
2499 (
<literal>*
</literal>) as well as the non-grantable
2500 privilege
<literal>UPDATE
</literal> (
<literal>w
</literal>), both granted
2501 by the role
<literal>hobbes
</literal>. If
<literal>calvin
</literal>
2502 also has some privileges on the same object granted by a different
2503 grantor, those would appear as a separate
<type>aclitem
</type> entry.
2504 An empty grantee field in an
<type>aclitem
</type> stands
2505 for
<literal>PUBLIC
</literal>.
2509 As an example, suppose that user
<literal>miriam
</literal> creates
2510 table
<literal>mytable
</literal> and does:
2512 GRANT SELECT ON mytable TO PUBLIC;
2513 GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
2514 GRANT SELECT (col1), UPDATE (col1) ON mytable TO miriam_rw;
2516 Then
<application>psql
</application>'s
<literal>\dp
</literal> command
2521 Schema | Name | Type | Access privileges | Column privileges | Policies
2522 --------+---------+-------+------------------------+-----------------------+----------
2523 public | mytable | table | miriam=arwdDxtm/miriam+| col1: +|
2524 | | | =r/miriam +| miriam_rw=rw/miriam |
2525 | | | admin=arw/miriam | |
2531 If the
<quote>Access privileges
</quote> column is empty for a given
2532 object, it means the object has default privileges (that is, its
2533 privileges entry in the relevant system catalog is null). Default
2534 privileges always include all privileges for the owner, and can include
2535 some privileges for
<literal>PUBLIC
</literal> depending on the object
2536 type, as explained above. The first
<command>GRANT
</command>
2537 or
<command>REVOKE
</command> on an object will instantiate the default
2538 privileges (producing, for
2539 example,
<literal>miriam=arwdDxt/miriam
</literal>) and then modify them
2540 per the specified request. Similarly, entries are shown in
<quote>Column
2541 privileges
</quote> only for columns with nondefault privileges.
2542 (Note: for this purpose,
<quote>default privileges
</quote> always means
2543 the built-in default privileges for the object's type. An object whose
2544 privileges have been affected by an
<command>ALTER DEFAULT
2545 PRIVILEGES
</command> command will always be shown with an explicit
2546 privilege entry that includes the effects of
2547 the
<command>ALTER
</command>.)
2551 Notice that the owner's implicit grant options are not marked in the
2552 access privileges display. A
<literal>*
</literal> will appear only when
2553 grant options have been explicitly granted to someone.
2557 The
<quote>Access privileges
</quote> column
2558 shows
<literal>(none)
</literal> when the object's privileges entry is
2559 non-null but empty. This means that no privileges are granted at all,
2560 even to the object's owner
— a rare situation. (The owner still
2561 has implicit grant options in this case, and so could re-grant her own
2562 privileges; but she has none at the moment.)
2566 <sect1 id=
"ddl-rowsecurity">
2567 <title>Row Security Policies
</title>
2569 <indexterm zone=
"ddl-rowsecurity">
2570 <primary>row-level security
</primary>
2573 <indexterm zone=
"ddl-rowsecurity">
2574 <primary>policy
</primary>
2578 In addition to the SQL-standard
<link linkend=
"ddl-priv">privilege
2579 system
</link> available through
<xref linkend=
"sql-grant"/>,
2580 tables can have
<firstterm>row security policies
</firstterm> that restrict,
2581 on a per-user basis, which rows can be returned by normal queries
2582 or inserted, updated, or deleted by data modification commands.
2583 This feature is also known as
<firstterm>Row-Level Security
</firstterm>.
2584 By default, tables do not have any policies, so that if a user has
2585 access privileges to a table according to the SQL privilege system,
2586 all rows within it are equally available for querying or updating.
2590 When row security is enabled on a table (with
2591 <link linkend=
"sql-altertable">ALTER TABLE ... ENABLE ROW LEVEL
2592 SECURITY
</link>), all normal access to the table for selecting rows or
2593 modifying rows must be allowed by a row security policy. (However, the
2594 table's owner is typically not subject to row security policies.) If no
2595 policy exists for the table, a default-deny policy is used, meaning that
2596 no rows are visible or can be modified. Operations that apply to the
2597 whole table, such as
<command>TRUNCATE
</command> and
<literal>REFERENCES
</literal>,
2598 are not subject to row security.
2602 Row security policies can be specific to commands, or to roles, or to
2603 both. A policy can be specified to apply to
<literal>ALL
</literal>
2604 commands, or to
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
<literal>UPDATE
</literal>,
2605 or
<literal>DELETE
</literal>. Multiple roles can be assigned to a given
2606 policy, and normal role membership and inheritance rules apply.
2610 To specify which rows are visible or modifiable according to a policy,
2611 an expression is required that returns a Boolean result. This
2612 expression will be evaluated for each row prior to any conditions or
2613 functions coming from the user's query. (The only exceptions to this
2614 rule are
<literal>leakproof
</literal> functions, which are guaranteed to
2615 not leak information; the optimizer may choose to apply such functions
2616 ahead of the row-security check.) Rows for which the expression does
2617 not return
<literal>true
</literal> will not be processed. Separate expressions
2618 may be specified to provide independent control over the rows which are
2619 visible and the rows which are allowed to be modified. Policy
2620 expressions are run as part of the query and with the privileges of the
2621 user running the query, although security-definer functions can be used
2622 to access data not available to the calling user.
2626 Superusers and roles with the
<literal>BYPASSRLS
</literal> attribute always
2627 bypass the row security system when accessing a table. Table owners
2628 normally bypass row security as well, though a table owner can choose to
2629 be subject to row security with
<link linkend=
"sql-altertable">ALTER
2630 TABLE ... FORCE ROW LEVEL SECURITY
</link>.
2634 Enabling and disabling row security, as well as adding policies to a
2635 table, is always the privilege of the table owner only.
2639 Policies are created using the
<xref linkend=
"sql-createpolicy"/>
2640 command, altered using the
<xref linkend=
"sql-alterpolicy"/> command,
2641 and dropped using the
<xref linkend=
"sql-droppolicy"/> command. To
2642 enable and disable row security for a given table, use the
2643 <xref linkend=
"sql-altertable"/> command.
2647 Each policy has a name and multiple policies can be defined for a
2648 table. As policies are table-specific, each policy for a table must
2649 have a unique name. Different tables may have policies with the
2654 When multiple policies apply to a given query, they are combined using
2655 either
<literal>OR
</literal> (for permissive policies, which are the
2656 default) or using
<literal>AND
</literal> (for restrictive policies).
2657 The
<literal>OR
</literal> behavior is similar to the rule that a given
2658 role has the privileges
2659 of all roles that they are a member of. Permissive vs. restrictive
2660 policies are discussed further below.
2664 As a simple example, here is how to create a policy on
2665 the
<literal>account
</literal> relation to allow only members of
2666 the
<literal>managers
</literal> role to access rows, and only rows of their
2671 CREATE TABLE accounts (manager text, company text, contact_email text);
2673 ALTER TABLE accounts ENABLE ROW LEVEL SECURITY;
2675 CREATE POLICY account_managers ON accounts TO managers
2676 USING (manager = current_user);
2680 The policy above implicitly provides a
<literal>WITH CHECK
</literal>
2681 clause identical to its
<literal>USING
</literal> clause, so that the
2682 constraint applies both to rows selected by a command (so a manager
2683 cannot
<command>SELECT
</command>,
<command>UPDATE
</command>,
2684 or
<command>DELETE
</command> existing rows belonging to a different
2685 manager) and to rows modified by a command (so rows belonging to a
2686 different manager cannot be created via
<command>INSERT
</command>
2687 or
<command>UPDATE
</command>).
2691 If no role is specified, or the special user name
2692 <literal>PUBLIC
</literal> is used, then the policy applies to all
2693 users on the system. To allow all users to access only their own row in
2694 a
<literal>users
</literal> table, a simple policy can be used:
2698 CREATE POLICY user_policy ON users
2699 USING (user_name = current_user);
2703 This works similarly to the previous example.
2707 To use a different policy for rows that are being added to the table
2708 compared to those rows that are visible, multiple policies can be
2709 combined. This pair of policies would allow all users to view all rows
2710 in the
<literal>users
</literal> table, but only modify their own:
2714 CREATE POLICY user_sel_policy ON users
2717 CREATE POLICY user_mod_policy ON users
2718 USING (user_name = current_user);
2722 In a
<command>SELECT
</command> command, these two policies are combined
2723 using
<literal>OR
</literal>, with the net effect being that all rows
2724 can be selected. In other command types, only the second policy applies,
2725 so that the effects are the same as before.
2729 Row security can also be disabled with the
<command>ALTER TABLE
</command>
2730 command. Disabling row security does not remove any policies that are
2731 defined on the table; they are simply ignored. Then all rows in the
2732 table are visible and modifiable, subject to the standard SQL privileges
2737 Below is a larger example of how this feature can be used in production
2738 environments. The table
<literal>passwd
</literal> emulates a Unix password
2743 -- Simple passwd-file based example
2744 CREATE TABLE passwd (
2745 user_name text UNIQUE NOT NULL,
2747 uid int PRIMARY KEY,
2749 real_name text NOT NULL,
2752 home_dir text NOT NULL,
2756 CREATE ROLE admin; -- Administrator
2757 CREATE ROLE bob; -- Normal user
2758 CREATE ROLE alice; -- Normal user
2760 -- Populate the table
2761 INSERT INTO passwd VALUES
2762 ('admin','xxx',
0,
0,'Admin','
111-
222-
3333',null,'/root','/bin/dash');
2763 INSERT INTO passwd VALUES
2764 ('bob','xxx',
1,
1,'Bob','
123-
456-
7890',null,'/home/bob','/bin/zsh');
2765 INSERT INTO passwd VALUES
2766 ('alice','xxx',
2,
1,'Alice','
098-
765-
4321',null,'/home/alice','/bin/zsh');
2768 -- Be sure to enable row-level security on the table
2769 ALTER TABLE passwd ENABLE ROW LEVEL SECURITY;
2772 -- Administrator can see all rows and add any rows
2773 CREATE POLICY admin_all ON passwd TO admin USING (true) WITH CHECK (true);
2774 -- Normal users can view all rows
2775 CREATE POLICY all_view ON passwd FOR SELECT USING (true);
2776 -- Normal users can update their own records, but
2777 -- limit which shells a normal user is allowed to set
2778 CREATE POLICY user_mod ON passwd FOR UPDATE
2779 USING (current_user = user_name)
2781 current_user = user_name AND
2782 shell IN ('/bin/bash','/bin/sh','/bin/dash','/bin/zsh','/bin/tcsh')
2785 -- Allow admin all normal rights
2786 GRANT SELECT, INSERT, UPDATE, DELETE ON passwd TO admin;
2787 -- Users only get select access on public columns
2789 (user_name, uid, gid, real_name, home_phone, extra_info, home_dir, shell)
2790 ON passwd TO public;
2791 -- Allow users to update certain columns
2793 (pwhash, real_name, home_phone, extra_info, shell)
2794 ON passwd TO public;
2798 As with any security settings, it's important to test and ensure that
2799 the system is behaving as expected. Using the example above, this
2800 demonstrates that the permission system is working properly.
2804 -- admin can view all rows and fields
2805 postgres=
> set role admin;
2807 postgres=
> table passwd;
2808 user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
2809 -----------+--------+-----+-----+-----------+--------------+------------+-------------+-----------
2810 admin | xxx |
0 |
0 | Admin |
111-
222-
3333 | | /root | /bin/dash
2811 bob | xxx |
1 |
1 | Bob |
123-
456-
7890 | | /home/bob | /bin/zsh
2812 alice | xxx |
2 |
1 | Alice |
098-
765-
4321 | | /home/alice | /bin/zsh
2815 -- Test what Alice is able to do
2816 postgres=
> set role alice;
2818 postgres=
> table passwd;
2819 ERROR: permission denied for table passwd
2820 postgres=
> select user_name,real_name,home_phone,extra_info,home_dir,shell from passwd;
2821 user_name | real_name | home_phone | extra_info | home_dir | shell
2822 -----------+-----------+--------------+------------+-------------+-----------
2823 admin | Admin |
111-
222-
3333 | | /root | /bin/dash
2824 bob | Bob |
123-
456-
7890 | | /home/bob | /bin/zsh
2825 alice | Alice |
098-
765-
4321 | | /home/alice | /bin/zsh
2828 postgres=
> update passwd set user_name = 'joe';
2829 ERROR: permission denied for table passwd
2830 -- Alice is allowed to change her own real_name, but no others
2831 postgres=
> update passwd set real_name = 'Alice Doe';
2833 postgres=
> update passwd set real_name = 'John Doe' where user_name = 'admin';
2835 postgres=
> update passwd set shell = '/bin/xx';
2836 ERROR: new row violates WITH CHECK OPTION for
"passwd"
2837 postgres=
> delete from passwd;
2838 ERROR: permission denied for table passwd
2839 postgres=
> insert into passwd (user_name) values ('xxx');
2840 ERROR: permission denied for table passwd
2841 -- Alice can change her own password; RLS silently prevents updating other rows
2842 postgres=
> update passwd set pwhash = 'abc';
2847 All of the policies constructed thus far have been permissive policies,
2848 meaning that when multiple policies are applied they are combined using
2849 the
<quote>OR
</quote> Boolean operator. While permissive policies can be constructed
2850 to only allow access to rows in the intended cases, it can be simpler to
2851 combine permissive policies with restrictive policies (which the records
2852 must pass and which are combined using the
<quote>AND
</quote> Boolean operator).
2853 Building on the example above, we add a restrictive policy to require
2854 the administrator to be connected over a local Unix socket to access the
2855 records of the
<literal>passwd
</literal> table:
2859 CREATE POLICY admin_local_only ON passwd AS RESTRICTIVE TO admin
2860 USING (pg_catalog.inet_client_addr() IS NULL);
2864 We can then see that an administrator connecting over a network will not
2865 see any records, due to the restrictive policy:
2869 =
> SELECT current_user;
2875 =
> select inet_client_addr();
2882 user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
2883 -----------+--------+-----+-----+-----------+------------+------------+----------+-------
2886 =
> UPDATE passwd set pwhash = NULL;
2891 Referential integrity checks, such as unique or primary key constraints
2892 and foreign key references, always bypass row security to ensure that
2893 data integrity is maintained. Care must be taken when developing
2894 schemas and row level policies to avoid
<quote>covert channel
</quote> leaks of
2895 information through such referential integrity checks.
2899 In some contexts it is important to be sure that row security is
2900 not being applied. For example, when taking a backup, it could be
2901 disastrous if row security silently caused some rows to be omitted
2902 from the backup. In such a situation, you can set the
2903 <xref linkend=
"guc-row-security"/> configuration parameter
2904 to
<literal>off
</literal>. This does not in itself bypass row security;
2905 what it does is throw an error if any query's results would get filtered
2906 by a policy. The reason for the error can then be investigated and
2911 In the examples above, the policy expressions consider only the current
2912 values in the row to be accessed or updated. This is the simplest and
2913 best-performing case; when possible, it's best to design row security
2914 applications to work this way. If it is necessary to consult other rows
2915 or other tables to make a policy decision, that can be accomplished using
2916 sub-
<command>SELECT
</command>s, or functions that contain
<command>SELECT
</command>s,
2917 in the policy expressions. Be aware however that such accesses can
2918 create race conditions that could allow information leakage if care is
2919 not taken. As an example, consider the following table design:
2923 -- definition of privilege groups
2924 CREATE TABLE groups (group_id int PRIMARY KEY,
2925 group_name text NOT NULL);
2927 INSERT INTO groups VALUES
2932 GRANT ALL ON groups TO alice; -- alice is the administrator
2933 GRANT SELECT ON groups TO public;
2935 -- definition of users' privilege levels
2936 CREATE TABLE users (user_name text PRIMARY KEY,
2937 group_id int NOT NULL REFERENCES groups);
2939 INSERT INTO users VALUES
2944 GRANT ALL ON users TO alice;
2945 GRANT SELECT ON users TO public;
2947 -- table holding the information to be protected
2948 CREATE TABLE information (info text,
2949 group_id int NOT NULL REFERENCES groups);
2951 INSERT INTO information VALUES
2952 ('barely secret',
1),
2953 ('slightly secret',
2),
2956 ALTER TABLE information ENABLE ROW LEVEL SECURITY;
2958 -- a row should be visible to/updatable by users whose security group_id is
2959 -- greater than or equal to the row's group_id
2960 CREATE POLICY fp_s ON information FOR SELECT
2961 USING (group_id
<= (SELECT group_id FROM users WHERE user_name = current_user));
2962 CREATE POLICY fp_u ON information FOR UPDATE
2963 USING (group_id
<= (SELECT group_id FROM users WHERE user_name = current_user));
2965 -- we rely only on RLS to protect the information table
2966 GRANT ALL ON information TO public;
2970 Now suppose that
<literal>alice
</literal> wishes to change the
<quote>slightly
2971 secret
</quote> information, but decides that
<literal>mallory
</literal> should not
2972 be trusted with the new content of that row, so she does:
2977 UPDATE users SET group_id =
1 WHERE user_name = 'mallory';
2978 UPDATE information SET info = 'secret from mallory' WHERE group_id =
2;
2983 That looks safe; there is no window wherein
<literal>mallory
</literal> should be
2984 able to see the
<quote>secret from mallory
</quote> string. However, there is
2985 a race condition here. If
<literal>mallory
</literal> is concurrently doing,
2988 SELECT * FROM information WHERE group_id =
2 FOR UPDATE;
2990 and her transaction is in
<literal>READ COMMITTED
</literal> mode, it is possible
2991 for her to see
<quote>secret from mallory
</quote>. That happens if her
2992 transaction reaches the
<structname>information
</structname> row just
2993 after
<literal>alice
</literal>'s does. It blocks waiting
2994 for
<literal>alice
</literal>'s transaction to commit, then fetches the updated
2995 row contents thanks to the
<literal>FOR UPDATE
</literal> clause. However, it
2996 does
<emphasis>not
</emphasis> fetch an updated row for the
2997 implicit
<command>SELECT
</command> from
<structname>users
</structname>, because that
2998 sub-
<command>SELECT
</command> did not have
<literal>FOR UPDATE
</literal>; instead
2999 the
<structname>users
</structname> row is read with the snapshot taken at the start
3000 of the query. Therefore, the policy expression tests the old value
3001 of
<literal>mallory
</literal>'s privilege level and allows her to see the
3006 There are several ways around this problem. One simple answer is to use
3007 <literal>SELECT ... FOR SHARE
</literal> in sub-
<command>SELECT
</command>s in row
3008 security policies. However, that requires granting
<literal>UPDATE
</literal>
3009 privilege on the referenced table (here
<structname>users
</structname>) to the
3010 affected users, which might be undesirable. (But another row security
3011 policy could be applied to prevent them from actually exercising that
3012 privilege; or the sub-
<command>SELECT
</command> could be embedded into a security
3013 definer function.) Also, heavy concurrent use of row share locks on the
3014 referenced table could pose a performance problem, especially if updates
3015 of it are frequent. Another solution, practical if updates of the
3016 referenced table are infrequent, is to take an
3017 <literal>ACCESS EXCLUSIVE
</literal> lock on the
3018 referenced table when updating it, so that no concurrent transactions
3019 could be examining old row values. Or one could just wait for all
3020 concurrent transactions to end after committing an update of the
3021 referenced table and before making changes that rely on the new security
3026 For additional details see
<xref linkend=
"sql-createpolicy"/>
3027 and
<xref linkend=
"sql-altertable"/>.
3032 <sect1 id=
"ddl-schemas">
3033 <title>Schemas
</title>
3035 <indexterm zone=
"ddl-schemas">
3036 <primary>schema
</primary>
3040 A
<productname>PostgreSQL
</productname> database cluster contains
3041 one or more named databases. Roles and a few other object types are
3042 shared across the entire cluster. A client connection to the server
3043 can only access data in a single database, the one specified in the
3049 Users of a cluster do not necessarily have the privilege to access every
3050 database in the cluster. Sharing of role names means that there
3051 cannot be different roles named, say,
<literal>joe
</literal> in two databases
3052 in the same cluster; but the system can be configured to allow
3053 <literal>joe
</literal> access to only some of the databases.
3058 A database contains one or more named
<firstterm>schemas
</firstterm>, which
3059 in turn contain tables. Schemas also contain other kinds of named
3060 objects, including data types, functions, and operators. Within one
3061 schema, two objects of the same type cannot have the same name.
3062 Furthermore, tables, sequences, indexes, views, materialized views, and
3063 foreign tables share the same namespace, so that, for example, an index and
3064 a table must have different names if they are in the same schema. The same
3065 object name can be used in different schemas without conflict; for
3066 example, both
<literal>schema1
</literal> and
<literal>myschema
</literal> can
3067 contain tables named
<literal>mytable
</literal>. Unlike databases,
3068 schemas are not rigidly separated: a user can access objects in any
3069 of the schemas in the database they are connected to, if they have
3070 privileges to do so.
3074 There are several reasons why one might want to use schemas:
3079 To allow many users to use one database without interfering with
3086 To organize database objects into logical groups to make them
3093 Third-party applications can be put into separate schemas so
3094 they do not collide with the names of other objects.
3099 Schemas are analogous to directories at the operating system level,
3100 except that schemas cannot be nested.
3103 <sect2 id=
"ddl-schemas-create">
3104 <title>Creating a Schema
</title>
3106 <indexterm zone=
"ddl-schemas-create">
3107 <primary>schema
</primary>
3108 <secondary>creating
</secondary>
3112 To create a schema, use the
<xref linkend=
"sql-createschema"/>
3113 command. Give the schema a name
3114 of your choice. For example:
3116 CREATE SCHEMA myschema;
3121 <primary>qualified name
</primary>
3125 <primary>name
</primary>
3126 <secondary>qualified
</secondary>
3130 To create or access objects in a schema, write a
3131 <firstterm>qualified name
</firstterm> consisting of the schema name and
3132 table name separated by a dot:
3134 <replaceable>schema
</replaceable><literal>.
</literal><replaceable>table
</replaceable>
3136 This works anywhere a table name is expected, including the table
3137 modification commands and the data access commands discussed in
3138 the following chapters.
3139 (For brevity we will speak of tables only, but the same ideas apply
3140 to other kinds of named objects, such as types and functions.)
3144 Actually, the even more general syntax
3146 <replaceable>database
</replaceable><literal>.
</literal><replaceable>schema
</replaceable><literal>.
</literal><replaceable>table
</replaceable>
3148 can be used too, but at present this is just for pro forma
3149 compliance with the SQL standard. If you write a database name,
3150 it must be the same as the database you are connected to.
3154 So to create a table in the new schema, use:
3156 CREATE TABLE myschema.mytable (
3163 <primary>schema
</primary>
3164 <secondary>removing
</secondary>
3168 To drop a schema if it's empty (all objects in it have been
3171 DROP SCHEMA myschema;
3173 To drop a schema including all contained objects, use:
3175 DROP SCHEMA myschema CASCADE;
3177 See
<xref linkend=
"ddl-depend"/> for a description of the general
3178 mechanism behind this.
3182 Often you will want to create a schema owned by someone else
3183 (since this is one of the ways to restrict the activities of your
3184 users to well-defined namespaces). The syntax for that is:
3186 CREATE SCHEMA
<replaceable>schema_name
</replaceable> AUTHORIZATION
<replaceable>user_name
</replaceable>;
3188 You can even omit the schema name, in which case the schema name
3189 will be the same as the user name. See
<xref
3190 linkend=
"ddl-schemas-patterns"/> for how this can be useful.
3194 Schema names beginning with
<literal>pg_
</literal> are reserved for
3195 system purposes and cannot be created by users.
3199 <sect2 id=
"ddl-schemas-public">
3200 <title>The Public Schema
</title>
3202 <indexterm zone=
"ddl-schemas-public">
3203 <primary>schema
</primary>
3204 <secondary>public
</secondary>
3208 In the previous sections we created tables without specifying any
3209 schema names. By default such tables (and other objects) are
3210 automatically put into a schema named
<quote>public
</quote>. Every new
3211 database contains such a schema. Thus, the following are equivalent:
3213 CREATE TABLE products ( ... );
3217 CREATE TABLE public.products ( ... );
3222 <sect2 id=
"ddl-schemas-path">
3223 <title>The Schema Search Path
</title>
3226 <primary>search path
</primary>
3230 <primary>unqualified name
</primary>
3234 <primary>name
</primary>
3235 <secondary>unqualified
</secondary>
3239 Qualified names are tedious to write, and it's often best not to
3240 wire a particular schema name into applications anyway. Therefore
3241 tables are often referred to by
<firstterm>unqualified names
</firstterm>,
3242 which consist of just the table name. The system determines which table
3243 is meant by following a
<firstterm>search path
</firstterm>, which is a list
3244 of schemas to look in. The first matching table in the search path
3245 is taken to be the one wanted. If there is no match in the search
3246 path, an error is reported, even if matching table names exist
3247 in other schemas in the database.
3251 The ability to create like-named objects in different schemas complicates
3252 writing a query that references precisely the same objects every time. It
3253 also opens up the potential for users to change the behavior of other
3254 users' queries, maliciously or accidentally. Due to the prevalence of
3255 unqualified names in queries and their use
3256 in
<productname>PostgreSQL
</productname> internals, adding a schema
3257 to
<varname>search_path
</varname> effectively trusts all users having
3258 <literal>CREATE
</literal> privilege on that schema. When you run an
3259 ordinary query, a malicious user able to create objects in a schema of
3260 your search path can take control and execute arbitrary SQL functions as
3261 though you executed them.
3265 <primary>schema
</primary>
3266 <secondary>current
</secondary>
3270 The first schema named in the search path is called the current schema.
3271 Aside from being the first schema searched, it is also the schema in
3272 which new tables will be created if the
<command>CREATE TABLE
</command>
3273 command does not specify a schema name.
3277 <primary><varname>search_path
</varname> configuration parameter
</primary>
3281 To show the current search path, use the following command:
3285 In the default setup this returns:
3291 The first element specifies that a schema with the same name as
3292 the current user is to be searched. If no such schema exists,
3293 the entry is ignored. The second element refers to the
3294 public schema that we have seen already.
3298 The first schema in the search path that exists is the default
3299 location for creating new objects. That is the reason that by
3300 default objects are created in the public schema. When objects
3301 are referenced in any other context without schema qualification
3302 (table modification, data modification, or query commands) the
3303 search path is traversed until a matching object is found.
3304 Therefore, in the default configuration, any unqualified access
3305 again can only refer to the public schema.
3309 To put our new schema in the path, we use:
3311 SET search_path TO myschema,public;
3313 (We omit the
<literal>$user
</literal> here because we have no
3314 immediate need for it.) And then we can access the table without
3315 schema qualification:
3319 Also, since
<literal>myschema
</literal> is the first element in
3320 the path, new objects would by default be created in it.
3324 We could also have written:
3326 SET search_path TO myschema;
3328 Then we no longer have access to the public schema without
3329 explicit qualification. There is nothing special about the public
3330 schema except that it exists by default. It can be dropped, too.
3334 See also
<xref linkend=
"functions-info"/> for other ways to manipulate
3335 the schema search path.
3339 The search path works in the same way for data type names, function names,
3340 and operator names as it does for table names. Data type and function
3341 names can be qualified in exactly the same way as table names. If you
3342 need to write a qualified operator name in an expression, there is a
3343 special provision: you must write
3345 <literal>OPERATOR(
</literal><replaceable>schema
</replaceable><literal>.
</literal><replaceable>operator
</replaceable><literal>)
</literal>
3347 This is needed to avoid syntactic ambiguity. An example is:
3349 SELECT
3 OPERATOR(pg_catalog.+)
4;
3351 In practice one usually relies on the search path for operators,
3352 so as not to have to write anything so ugly as that.
3356 <sect2 id=
"ddl-schemas-priv">
3357 <title>Schemas and Privileges
</title>
3359 <indexterm zone=
"ddl-schemas-priv">
3360 <primary>privilege
</primary>
3361 <secondary sortas=
"schemas">for schemas
</secondary>
3365 By default, users cannot access any objects in schemas they do not
3366 own. To allow that, the owner of the schema must grant the
3367 <literal>USAGE
</literal> privilege on the schema. By default, everyone
3368 has that privilege on the schema
<literal>public
</literal>. To allow
3369 users to make use of the objects in a schema, additional privileges might
3370 need to be granted, as appropriate for the object.
3374 A user can also be allowed to create objects in someone else's schema. To
3375 allow that, the
<literal>CREATE
</literal> privilege on the schema needs to
3376 be granted. In databases upgraded from
3377 <productname>PostgreSQL
</productname> 14 or earlier, everyone has that
3378 privilege on the schema
<literal>public
</literal>.
3379 Some
<link linkend=
"ddl-schemas-patterns">usage patterns
</link> call for
3380 revoking that privilege:
3382 REVOKE CREATE ON SCHEMA public FROM PUBLIC;
3384 (The first
<quote>public
</quote> is the schema, the second
3385 <quote>public
</quote> means
<quote>every user
</quote>. In the
3386 first sense it is an identifier, in the second sense it is a
3387 key word, hence the different capitalization; recall the
3388 guidelines from
<xref linkend=
"sql-syntax-identifiers"/>.)
3392 <sect2 id=
"ddl-schemas-catalog">
3393 <title>The System Catalog Schema
</title>
3395 <indexterm zone=
"ddl-schemas-catalog">
3396 <primary>system catalog
</primary>
3397 <secondary>schema
</secondary>
3401 In addition to
<literal>public
</literal> and user-created schemas, each
3402 database contains a
<literal>pg_catalog
</literal> schema, which contains
3403 the system tables and all the built-in data types, functions, and
3404 operators.
<literal>pg_catalog
</literal> is always effectively part of
3405 the search path. If it is not named explicitly in the path then
3406 it is implicitly searched
<emphasis>before
</emphasis> searching the path's
3407 schemas. This ensures that built-in names will always be
3408 findable. However, you can explicitly place
3409 <literal>pg_catalog
</literal> at the end of your search path if you
3410 prefer to have user-defined names override built-in names.
3414 Since system table names begin with
<literal>pg_
</literal>, it is best to
3415 avoid such names to ensure that you won't suffer a conflict if some
3416 future version defines a system table named the same as your
3417 table. (With the default search path, an unqualified reference to
3418 your table name would then be resolved as the system table instead.)
3419 System tables will continue to follow the convention of having
3420 names beginning with
<literal>pg_
</literal>, so that they will not
3421 conflict with unqualified user-table names so long as users avoid
3422 the
<literal>pg_
</literal> prefix.
3426 <sect2 id=
"ddl-schemas-patterns">
3427 <title>Usage Patterns
</title>
3430 Schemas can be used to organize your data in many ways.
3431 A
<firstterm>secure schema usage pattern
</firstterm> prevents untrusted
3432 users from changing the behavior of other users' queries. When a database
3433 does not use a secure schema usage pattern, users wishing to securely
3434 query that database would take protective action at the beginning of each
3435 session. Specifically, they would begin each session by
3436 setting
<varname>search_path
</varname> to the empty string or otherwise
3437 removing schemas that are writable by non-superusers
3438 from
<varname>search_path
</varname>. There are a few usage patterns
3439 easily supported by the default configuration:
3443 Constrain ordinary users to user-private schemas.
3444 To implement this pattern, first ensure that no schemas have
3445 public
<literal>CREATE
</literal> privileges. Then, for every user
3446 needing to create non-temporary objects, create a schema with the
3447 same name as that user, for example
3448 <literal>CREATE SCHEMA alice AUTHORIZATION alice
</literal>.
3449 (Recall that the default search path starts
3450 with
<literal>$user
</literal>, which resolves to the user
3451 name. Therefore, if each user has a separate schema, they access
3452 their own schemas by default.) This pattern is a secure schema
3453 usage pattern unless an untrusted user is the database owner or
3454 has been granted
<literal>ADMIN OPTION
</literal> on a relevant role,
3455 in which case no secure schema usage pattern exists.
3457 <!-- A database owner can attack the database's users via "CREATE SCHEMA
3458 trojan; ALTER DATABASE $mydb SET search_path = trojan, public;". -->
3461 In
<productname>PostgreSQL
</productname> 15 and later, the default
3462 configuration supports this usage pattern. In prior versions, or
3463 when using a database that has been upgraded from a prior version,
3464 you will need to remove the public
<literal>CREATE
</literal>
3465 privilege from the
<literal>public
</literal> schema (issue
3466 <literal>REVOKE CREATE ON SCHEMA public FROM PUBLIC
</literal>).
3467 Then consider auditing the
<literal>public
</literal> schema for
3468 objects named like objects in schema
<literal>pg_catalog
</literal>.
3470 <!-- "DROP SCHEMA public" is inferior to this REVOKE, because pg_dump
3471 doesn't preserve that DROP. -->
3476 Remove the public schema from the default search path, by modifying
3477 <link linkend=
"config-setting-configuration-file"><filename>postgresql.conf
</filename></link>
3478 or by issuing
<literal>ALTER ROLE ALL SET search_path =
3479 "$user"</literal>. Then, grant privileges to create in the public
3480 schema. Only qualified names will choose public schema objects. While
3481 qualified table references are fine, calls to functions in the public
3482 schema
<link linkend=
"typeconv-func">will be unsafe or
3483 unreliable
</link>. If you create functions or extensions in the public
3484 schema, use the first pattern instead. Otherwise, like the first
3485 pattern, this is secure unless an untrusted user is the database owner
3486 or has been granted
<literal>ADMIN OPTION
</literal> on a relevant role.
3492 Keep the default search path, and grant privileges to create in the
3493 public schema. All users access the public schema implicitly. This
3494 simulates the situation where schemas are not available at all, giving
3495 a smooth transition from the non-schema-aware world. However, this is
3496 never a secure pattern. It is acceptable only when the database has a
3497 single user or a few mutually-trusting users. In databases upgraded
3498 from
<productname>PostgreSQL
</productname> 14 or earlier, this is the
3506 For any pattern, to install shared applications (tables to be used by
3507 everyone, additional functions provided by third parties, etc.), put them
3508 into separate schemas. Remember to grant appropriate privileges to allow
3509 the other users to access them. Users can then refer to these additional
3510 objects by qualifying the names with a schema name, or they can put the
3511 additional schemas into their search path, as they choose.
3515 <sect2 id=
"ddl-schemas-portability">
3516 <title>Portability
</title>
3519 In the SQL standard, the notion of objects in the same schema
3520 being owned by different users does not exist. Moreover, some
3521 implementations do not allow you to create schemas that have a
3522 different name than their owner. In fact, the concepts of schema
3523 and user are nearly equivalent in a database system that
3524 implements only the basic schema support specified in the
3525 standard. Therefore, many users consider qualified names to
3527 <literal><replaceable>user_name
</replaceable>.
<replaceable>table_name
</replaceable></literal>.
3528 This is how
<productname>PostgreSQL
</productname> will effectively
3529 behave if you create a per-user schema for every user.
3533 Also, there is no concept of a
<literal>public
</literal> schema in the
3534 SQL standard. For maximum conformance to the standard, you should
3535 not use the
<literal>public
</literal> schema.
3539 Of course, some SQL database systems might not implement schemas
3540 at all, or provide namespace support by allowing (possibly
3541 limited) cross-database access. If you need to work with those
3542 systems, then maximum portability would be achieved by not using
3548 <sect1 id=
"ddl-inherit">
3549 <title>Inheritance
</title>
3552 <primary>inheritance
</primary>
3556 <primary>table
</primary>
3557 <secondary>inheritance
</secondary>
3561 <productname>PostgreSQL
</productname> implements table inheritance,
3562 which can be a useful tool for database designers. (SQL:
1999 and
3563 later define a type inheritance feature, which differs in many
3564 respects from the features described here.)
3568 Let's start with an example: suppose we are trying to build a data
3569 model for cities. Each state has many cities, but only one
3570 capital. We want to be able to quickly retrieve the capital city
3571 for any particular state. This can be done by creating two tables,
3572 one for state capitals and one for cities that are not
3573 capitals. However, what happens when we want to ask for data about
3574 a city, regardless of whether it is a capital or not? The
3575 inheritance feature can help to resolve this problem. We define the
3576 <structname>capitals
</structname> table so that it inherits from
3577 <structname>cities
</structname>:
3580 CREATE TABLE cities (
3583 elevation int -- in feet
3586 CREATE TABLE capitals (
3588 ) INHERITS (cities);
3591 In this case, the
<structname>capitals
</structname> table
<firstterm>inherits
</firstterm>
3592 all the columns of its parent table,
<structname>cities
</structname>. State
3593 capitals also have an extra column,
<structfield>state
</structfield>, that shows
3598 In
<productname>PostgreSQL
</productname>, a table can inherit from
3599 zero or more other tables, and a query can reference either all
3600 rows of a table or all rows of a table plus all of its descendant tables.
3601 The latter behavior is the default.
3602 For example, the following query finds the names of all cities,
3603 including state capitals, that are located at an elevation over
3607 SELECT name, elevation
3609 WHERE elevation
> 500;
3612 Given the sample data from the
<productname>PostgreSQL
</productname>
3613 tutorial (see
<xref linkend=
"tutorial-sql-intro"/>), this returns:
3617 -----------+-----------
3625 On the other hand, the following query finds all the cities that
3626 are not state capitals and are situated at an elevation over
500 feet:
3629 SELECT name, elevation
3631 WHERE elevation
> 500;
3634 -----------+-----------
3641 Here the
<literal>ONLY
</literal> keyword indicates that the query
3642 should apply only to
<structname>cities
</structname>, and not any tables
3643 below
<structname>cities
</structname> in the inheritance hierarchy. Many
3644 of the commands that we have already discussed
—
3645 <command>SELECT
</command>,
<command>UPDATE
</command> and
3646 <command>DELETE
</command> — support the
3647 <literal>ONLY
</literal> keyword.
3651 You can also write the table name with a trailing
<literal>*
</literal>
3652 to explicitly specify that descendant tables are included:
3655 SELECT name, elevation
3657 WHERE elevation
> 500;
3660 Writing
<literal>*
</literal> is not necessary, since this behavior is always
3661 the default. However, this syntax is still supported for
3662 compatibility with older releases where the default could be changed.
3666 In some cases you might wish to know which table a particular row
3667 originated from. There is a system column called
3668 <structfield>tableoid
</structfield> in each table which can tell you the
3672 SELECT c.tableoid, c.name, c.elevation
3674 WHERE c.elevation
> 500;
3680 tableoid | name | elevation
3681 ----------+-----------+-----------
3682 139793 | Las Vegas |
2174
3683 139793 | Mariposa |
1953
3684 139798 | Madison |
845
3687 (If you try to reproduce this example, you will probably get
3688 different numeric OIDs.) By doing a join with
3689 <structname>pg_class
</structname> you can see the actual table names:
3692 SELECT p.relname, c.name, c.elevation
3693 FROM cities c, pg_class p
3694 WHERE c.elevation
> 500 AND c.tableoid = p.oid;
3700 relname | name | elevation
3701 ----------+-----------+-----------
3702 cities | Las Vegas |
2174
3703 cities | Mariposa |
1953
3704 capitals | Madison |
845
3709 Another way to get the same effect is to use the
<type>regclass
</type>
3710 alias type, which will print the table OID symbolically:
3713 SELECT c.tableoid::regclass, c.name, c.elevation
3715 WHERE c.elevation
> 500;
3720 Inheritance does not automatically propagate data from
3721 <command>INSERT
</command> or
<command>COPY
</command> commands to
3722 other tables in the inheritance hierarchy. In our example, the
3723 following
<command>INSERT
</command> statement will fail:
3725 INSERT INTO cities (name, population, elevation, state)
3726 VALUES ('Albany', NULL, NULL, 'NY');
3728 We might hope that the data would somehow be routed to the
3729 <structname>capitals
</structname> table, but this does not happen:
3730 <command>INSERT
</command> always inserts into exactly the table
3731 specified. In some cases it is possible to redirect the insertion
3732 using a rule (see
<xref linkend=
"rules"/>). However that does not
3733 help for the above case because the
<structname>cities
</structname> table
3734 does not contain the column
<structfield>state
</structfield>, and so the
3735 command will be rejected before the rule can be applied.
3739 All check constraints and not-null constraints on a parent table are
3740 automatically inherited by its children, unless explicitly specified
3741 otherwise with
<literal>NO INHERIT
</literal> clauses. Other types of constraints
3742 (unique, primary key, and foreign key constraints) are not inherited.
3746 A table can inherit from more than one parent table, in which case it has
3747 the union of the columns defined by the parent tables. Any columns
3748 declared in the child table's definition are added to these. If the
3749 same column name appears in multiple parent tables, or in both a parent
3750 table and the child's definition, then these columns are
<quote>merged
</quote>
3751 so that there is only one such column in the child table. To be merged,
3752 columns must have the same data types, else an error is raised.
3753 Inheritable check constraints and not-null constraints are merged in a
3754 similar fashion. Thus, for example, a merged column will be marked
3755 not-null if any one of the column definitions it came from is marked
3756 not-null. Check constraints are merged if they have the same name,
3757 and the merge will fail if their conditions are different.
3761 Table inheritance is typically established when the child table is
3762 created, using the
<literal>INHERITS
</literal> clause of the
3763 <link linkend=
"sql-createtable"><command>CREATE TABLE
</command></link>
3765 Alternatively, a table which is already defined in a compatible way can
3766 have a new parent relationship added, using the
<literal>INHERIT
</literal>
3767 variant of
<link linkend=
"sql-altertable"><command>ALTER TABLE
</command></link>.
3768 To do this the new child table must already include columns with
3769 the same names and types as the columns of the parent. It must also include
3770 check constraints with the same names and check expressions as those of the
3771 parent. Similarly an inheritance link can be removed from a child using the
3772 <literal>NO INHERIT
</literal> variant of
<command>ALTER TABLE
</command>.
3773 Dynamically adding and removing inheritance links like this can be useful
3774 when the inheritance relationship is being used for table
3775 partitioning (see
<xref linkend=
"ddl-partitioning"/>).
3779 One convenient way to create a compatible table that will later be made
3780 a new child is to use the
<literal>LIKE
</literal> clause in
<command>CREATE
3781 TABLE
</command>. This creates a new table with the same columns as
3782 the source table. If there are any
<literal>CHECK
</literal>
3783 constraints defined on the source table, the
<literal>INCLUDING
3784 CONSTRAINTS
</literal> option to
<literal>LIKE
</literal> should be
3785 specified, as the new child must have constraints matching the parent
3786 to be considered compatible.
3790 A parent table cannot be dropped while any of its children remain. Neither
3791 can columns or check constraints of child tables be dropped or altered
3792 if they are inherited
3793 from any parent tables. If you wish to remove a table and all of its
3794 descendants, one easy way is to drop the parent table with the
3795 <literal>CASCADE
</literal> option (see
<xref linkend=
"ddl-depend"/>).
3799 <command>ALTER TABLE
</command> will
3800 propagate any changes in column data definitions and check
3801 constraints down the inheritance hierarchy. Again, dropping
3802 columns that are depended on by other tables is only possible when using
3803 the
<literal>CASCADE
</literal> option.
<command>ALTER
3804 TABLE
</command> follows the same rules for duplicate column merging
3805 and rejection that apply during
<command>CREATE TABLE
</command>.
3809 Inherited queries perform access permission checks on the parent table
3810 only. Thus, for example, granting
<literal>UPDATE
</literal> permission on
3811 the
<structname>cities
</structname> table implies permission to update rows in
3812 the
<structname>capitals
</structname> table as well, when they are
3813 accessed through
<structname>cities
</structname>. This preserves the appearance
3814 that the data is (also) in the parent table. But
3815 the
<structname>capitals
</structname> table could not be updated directly
3816 without an additional grant. In a similar way, the parent table's row
3817 security policies (see
<xref linkend=
"ddl-rowsecurity"/>) are applied to
3818 rows coming from child tables during an inherited query. A child table's
3819 policies, if any, are applied only when it is the table explicitly named
3820 in the query; and in that case, any policies attached to its parent(s) are
3825 Foreign tables (see
<xref linkend=
"ddl-foreign-data"/>) can also
3826 be part of inheritance hierarchies, either as parent or child
3827 tables, just as regular tables can be. If a foreign table is part
3828 of an inheritance hierarchy then any operations not supported by
3829 the foreign table are not supported on the whole hierarchy either.
3832 <sect2 id=
"ddl-inherit-caveats">
3833 <title>Caveats
</title>
3836 Note that not all SQL commands are able to work on
3837 inheritance hierarchies. Commands that are used for data querying,
3838 data modification, or schema modification
3839 (e.g.,
<literal>SELECT
</literal>,
<literal>UPDATE
</literal>,
<literal>DELETE
</literal>,
3840 most variants of
<literal>ALTER TABLE
</literal>, but
3841 not
<literal>INSERT
</literal> or
<literal>ALTER TABLE ...
3842 RENAME
</literal>) typically default to including child tables and
3843 support the
<literal>ONLY
</literal> notation to exclude them.
3844 The majority of commands that do database maintenance and tuning
3845 (e.g.,
<literal>REINDEX
</literal>) only work on individual, physical
3846 tables and do not support recursing over inheritance hierarchies.
3847 However, both
<literal>VACUUM
</literal> and
<literal>ANALYZE
</literal>
3848 commands default to including child tables and the
<literal>ONLY
</literal>
3849 notation is supported to allow them to be excluded. The respective
3850 behavior of each individual command is documented in its reference page
3851 (
<xref linkend=
"sql-commands"/>).
3855 A serious limitation of the inheritance feature is that indexes (including
3856 unique constraints) and foreign key constraints only apply to single
3857 tables, not to their inheritance children. This is true on both the
3858 referencing and referenced sides of a foreign key constraint. Thus,
3859 in the terms of the above example:
3864 If we declared
<structname>cities
</structname>.
<structfield>name
</structfield> to be
3865 <literal>UNIQUE
</literal> or a
<literal>PRIMARY KEY
</literal>, this would not stop the
3866 <structname>capitals
</structname> table from having rows with names duplicating
3867 rows in
<structname>cities
</structname>. And those duplicate rows would by
3868 default show up in queries from
<structname>cities
</structname>. In fact, by
3869 default
<structname>capitals
</structname> would have no unique constraint at all,
3870 and so could contain multiple rows with the same name.
3871 You could add a unique constraint to
<structname>capitals
</structname>, but this
3872 would not prevent duplication compared to
<structname>cities
</structname>.
3878 Similarly, if we were to specify that
3879 <structname>cities
</structname>.
<structfield>name
</structfield> <literal>REFERENCES
</literal> some
3880 other table, this constraint would not automatically propagate to
3881 <structname>capitals
</structname>. In this case you could work around it by
3882 manually adding the same
<literal>REFERENCES
</literal> constraint to
3883 <structname>capitals
</structname>.
3889 Specifying that another table's column
<literal>REFERENCES
3890 cities(name)
</literal> would allow the other table to contain city names, but
3891 not capital names. There is no good workaround for this case.
3896 Some functionality not implemented for inheritance hierarchies is
3897 implemented for declarative partitioning.
3898 Considerable care is needed in deciding whether partitioning with legacy
3899 inheritance is useful for your application.
3905 <sect1 id=
"ddl-partitioning">
3906 <title>Table Partitioning
</title>
3909 <primary>partitioning
</primary>
3913 <primary>table
</primary>
3914 <secondary>partitioning
</secondary>
3918 <primary>partitioned table
</primary>
3922 <productname>PostgreSQL
</productname> supports basic table
3923 partitioning. This section describes why and how to implement
3924 partitioning as part of your database design.
3927 <sect2 id=
"ddl-partitioning-overview">
3928 <title>Overview
</title>
3931 Partitioning refers to splitting what is logically one large table into
3932 smaller physical pieces. Partitioning can provide several benefits:
3936 Query performance can be improved dramatically in certain situations,
3937 particularly when most of the heavily accessed rows of the table are in a
3938 single partition or a small number of partitions. Partitioning
3939 effectively substitutes for the upper tree levels of indexes,
3940 making it more likely that the heavily-used parts of the indexes
3947 When queries or updates access a large percentage of a single
3948 partition, performance can be improved by using a
3949 sequential scan of that partition instead of using an
3950 index, which would require random-access reads scattered across the
3957 Bulk loads and deletes can be accomplished by adding or removing
3958 partitions, if the usage pattern is accounted for in the
3959 partitioning design. Dropping an individual partition
3960 using
<command>DROP TABLE
</command>, or doing
<command>ALTER TABLE
3961 DETACH PARTITION
</command>, is far faster than a bulk
3962 operation. These commands also entirely avoid the
3963 <command>VACUUM
</command> overhead caused by a bulk
<command>DELETE
</command>.
3969 Seldom-used data can be migrated to cheaper and slower storage media.
3974 These benefits will normally be worthwhile only when a table would
3975 otherwise be very large. The exact point at which a table will
3976 benefit from partitioning depends on the application, although a
3977 rule of thumb is that the size of the table should exceed the physical
3978 memory of the database server.
3982 <productname>PostgreSQL
</productname> offers built-in support for the
3983 following forms of partitioning:
3986 <varlistentry id=
"ddl-partitioning-overview-range">
3987 <term>Range Partitioning
</term>
3991 The table is partitioned into
<quote>ranges
</quote> defined
3992 by a key column or set of columns, with no overlap between
3993 the ranges of values assigned to different partitions. For
3994 example, one might partition by date ranges, or by ranges of
3995 identifiers for particular business objects.
3996 Each range's bounds are understood as being inclusive at the
3997 lower end and exclusive at the upper end. For example, if one
3998 partition's range is from
<literal>1</literal>
3999 to
<literal>10</literal>, and the next one's range is
4000 from
<literal>10</literal> to
<literal>20</literal>, then
4001 value
<literal>10</literal> belongs to the second partition not
4007 <varlistentry id=
"ddl-partitioning-overview-list">
4008 <term>List Partitioning
</term>
4012 The table is partitioned by explicitly listing which key value(s)
4013 appear in each partition.
4018 <varlistentry id=
"ddl-partitioning-overview-hash">
4019 <term>Hash Partitioning
</term>
4023 The table is partitioned by specifying a modulus and a remainder for
4024 each partition. Each partition will hold the rows for which the hash
4025 value of the partition key divided by the specified modulus will
4026 produce the specified remainder.
4032 If your application needs to use other forms of partitioning not listed
4033 above, alternative methods such as inheritance and
4034 <literal>UNION ALL
</literal> views can be used instead. Such methods
4035 offer flexibility but do not have some of the performance benefits
4036 of built-in declarative partitioning.
4040 <sect2 id=
"ddl-partitioning-declarative">
4041 <title>Declarative Partitioning
</title>
4044 <productname>PostgreSQL
</productname> allows you to declare
4045 that a table is divided into partitions. The table that is divided
4046 is referred to as a
<firstterm>partitioned table
</firstterm>. The
4047 declaration includes the
<firstterm>partitioning method
</firstterm>
4048 as described above, plus a list of columns or expressions to be used
4049 as the
<firstterm>partition key
</firstterm>.
4053 The partitioned table itself is a
<quote>virtual
</quote> table having
4054 no storage of its own. Instead, the storage belongs
4055 to
<firstterm>partitions
</firstterm>, which are otherwise-ordinary
4056 tables associated with the partitioned table.
4057 Each partition stores a subset of the data as defined by its
4058 <firstterm>partition bounds
</firstterm>.
4059 All rows inserted into a partitioned table will be routed to the
4060 appropriate one of the partitions based on the values of the partition
4062 Updating the partition key of a row will cause it to be moved into a
4063 different partition if it no longer satisfies the partition bounds
4064 of its original partition.
4068 Partitions may themselves be defined as partitioned tables, resulting
4069 in
<firstterm>sub-partitioning
</firstterm>. Although all partitions
4070 must have the same columns as their partitioned parent, partitions may
4072 own indexes, constraints and default values, distinct from those of other
4073 partitions. See
<xref linkend=
"sql-createtable"/> for more details on
4074 creating partitioned tables and partitions.
4078 It is not possible to turn a regular table into a partitioned table or
4079 vice versa. However, it is possible to add an existing regular or
4080 partitioned table as a partition of a partitioned table, or remove a
4081 partition from a partitioned table turning it into a standalone table;
4082 this can simplify and speed up many maintenance processes.
4083 See
<xref linkend=
"sql-altertable"/> to learn more about the
4084 <command>ATTACH PARTITION
</command> and
<command>DETACH PARTITION
</command>
4089 Partitions can also be
<link linkend=
"ddl-foreign-data">foreign
4090 tables
</link>, although considerable care is needed because it is then
4091 the user's responsibility that the contents of the foreign table
4092 satisfy the partitioning rule. There are some other restrictions as
4093 well. See
<xref linkend=
"sql-createforeigntable"/> for more
4097 <sect3 id=
"ddl-partitioning-declarative-example">
4098 <title>Example
</title>
4101 Suppose we are constructing a database for a large ice cream company.
4102 The company measures peak temperatures every day as well as ice cream
4103 sales in each region. Conceptually, we want a table like:
4106 CREATE TABLE measurement (
4107 city_id int not null,
4108 logdate date not null,
4114 We know that most queries will access just the last week's, month's or
4115 quarter's data, since the main use of this table will be to prepare
4116 online reports for management. To reduce the amount of old data that
4117 needs to be stored, we decide to keep only the most recent
3 years
4118 worth of data. At the beginning of each month we will remove the oldest
4119 month's data. In this situation we can use partitioning to help us meet
4120 all of our different requirements for the measurements table.
4124 To use declarative partitioning in this case, use the following steps:
4126 <orderedlist spacing=
"compact">
4129 Create the
<structname>measurement
</structname> table as a partitioned
4130 table by specifying the
<literal>PARTITION BY
</literal> clause, which
4131 includes the partitioning method (
<literal>RANGE
</literal> in this
4132 case) and the list of column(s) to use as the partition key.
4135 CREATE TABLE measurement (
4136 city_id int not null,
4137 logdate date not null,
4140 ) PARTITION BY RANGE (logdate);
4147 Create partitions. Each partition's definition must specify bounds
4148 that correspond to the partitioning method and partition key of the
4149 parent. Note that specifying bounds such that the new partition's
4150 values would overlap with those in one or more existing partitions will
4155 Partitions thus created are in every way normal
4156 <productname>PostgreSQL
</productname>
4157 tables (or, possibly, foreign tables). It is possible to specify a
4158 tablespace and storage parameters for each partition separately.
4162 For our example, each partition should hold one month's worth of
4163 data, to match the requirement of deleting one month's data at a
4164 time. So the commands might look like:
4167 CREATE TABLE measurement_y2006m02 PARTITION OF measurement
4168 FOR VALUES FROM ('
2006-
02-
01') TO ('
2006-
03-
01');
4170 CREATE TABLE measurement_y2006m03 PARTITION OF measurement
4171 FOR VALUES FROM ('
2006-
03-
01') TO ('
2006-
04-
01');
4174 CREATE TABLE measurement_y2007m11 PARTITION OF measurement
4175 FOR VALUES FROM ('
2007-
11-
01') TO ('
2007-
12-
01');
4177 CREATE TABLE measurement_y2007m12 PARTITION OF measurement
4178 FOR VALUES FROM ('
2007-
12-
01') TO ('
2008-
01-
01')
4179 TABLESPACE fasttablespace;
4181 CREATE TABLE measurement_y2008m01 PARTITION OF measurement
4182 FOR VALUES FROM ('
2008-
01-
01') TO ('
2008-
02-
01')
4183 WITH (parallel_workers =
4)
4184 TABLESPACE fasttablespace;
4187 (Recall that adjacent partitions can share a bound value, since
4188 range upper bounds are treated as exclusive bounds.)
4192 If you wish to implement sub-partitioning, again specify the
4193 <literal>PARTITION BY
</literal> clause in the commands used to create
4194 individual partitions, for example:
4197 CREATE TABLE measurement_y2006m02 PARTITION OF measurement
4198 FOR VALUES FROM ('
2006-
02-
01') TO ('
2006-
03-
01')
4199 PARTITION BY RANGE (peaktemp);
4202 After creating partitions of
<structname>measurement_y2006m02
</structname>,
4203 any data inserted into
<structname>measurement
</structname> that is mapped to
4204 <structname>measurement_y2006m02
</structname> (or data that is
4205 directly inserted into
<structname>measurement_y2006m02
</structname>,
4206 which is allowed provided its partition constraint is satisfied)
4207 will be further redirected to one of its
4208 partitions based on the
<structfield>peaktemp
</structfield> column. The partition
4209 key specified may overlap with the parent's partition key, although
4210 care should be taken when specifying the bounds of a sub-partition
4211 such that the set of data it accepts constitutes a subset of what
4212 the partition's own bounds allow; the system does not try to check
4213 whether that's really the case.
4217 Inserting data into the parent table that does not map
4218 to one of the existing partitions will cause an error; an appropriate
4219 partition must be added manually.
4223 It is not necessary to manually create table constraints describing
4224 the partition boundary conditions for partitions. Such constraints
4225 will be created automatically.
4231 Create an index on the key column(s), as well as any other indexes you
4232 might want, on the partitioned table. (The key index is not strictly
4233 necessary, but in most scenarios it is helpful.)
4234 This automatically creates a matching index on each partition, and
4235 any partitions you create or attach later will also have such an
4237 An index or unique constraint declared on a partitioned table
4238 is
<quote>virtual
</quote> in the same way that the partitioned table
4239 is: the actual data is in child indexes on the individual partition
4243 CREATE INDEX ON measurement (logdate);
4250 Ensure that the
<xref linkend=
"guc-enable-partition-pruning"/>
4251 configuration parameter is not disabled in
<filename>postgresql.conf
</filename>.
4252 If it is, queries will not be optimized as desired.
4259 In the above example we would be creating a new partition each month, so
4260 it might be wise to write a script that generates the required DDL
4265 <sect3 id=
"ddl-partitioning-declarative-maintenance">
4266 <title>Partition Maintenance
</title>
4269 Normally the set of partitions established when initially defining the
4270 table is not intended to remain static. It is common to want to
4271 remove partitions holding old data and periodically add new partitions for
4272 new data. One of the most important advantages of partitioning is
4273 precisely that it allows this otherwise painful task to be executed
4274 nearly instantaneously by manipulating the partition structure, rather
4275 than physically moving large amounts of data around.
4279 The simplest option for removing old data is to drop the partition that
4280 is no longer necessary:
4282 DROP TABLE measurement_y2006m02;
4284 This can very quickly delete millions of records because it doesn't have
4285 to individually delete every record. Note however that the above command
4286 requires taking an
<literal>ACCESS EXCLUSIVE
</literal> lock on the parent
4291 Another option that is often preferable is to remove the partition from
4292 the partitioned table but retain access to it as a table in its own
4293 right. This has two forms:
4296 ALTER TABLE measurement DETACH PARTITION measurement_y2006m02;
4297 ALTER TABLE measurement DETACH PARTITION measurement_y2006m02 CONCURRENTLY;
4300 These allow further operations to be performed on the data before
4301 it is dropped. For example, this is often a useful time to back up
4302 the data using
<command>COPY
</command>,
<application>pg_dump
</application>, or
4303 similar tools. It might also be a useful time to aggregate data
4304 into smaller formats, perform other data manipulations, or run
4305 reports. The first form of the command requires an
4306 <literal>ACCESS EXCLUSIVE
</literal> lock on the parent table.
4307 Adding the
<literal>CONCURRENTLY
</literal> qualifier as in the second
4308 form allows the detach operation to require only
4309 <literal>SHARE UPDATE EXCLUSIVE
</literal> lock on the parent table, but see
4310 <link linkend=
"sql-altertable-detach-partition"><literal>ALTER TABLE ... DETACH PARTITION
</literal></link>
4311 for details on the restrictions.
4315 Similarly we can add a new partition to handle new data. We can create an
4316 empty partition in the partitioned table just as the original partitions
4320 CREATE TABLE measurement_y2008m02 PARTITION OF measurement
4321 FOR VALUES FROM ('
2008-
02-
01') TO ('
2008-
03-
01')
4322 TABLESPACE fasttablespace;
4325 As an alternative to creating a new partition, it is sometimes more
4326 convenient to create a new table separate from the partition structure
4327 and attach it as a partition later. This allows new data to be loaded,
4328 checked, and transformed prior to it appearing in the partitioned table.
4329 Moreover, the
<literal>ATTACH PARTITION
</literal> operation requires
4330 only a
<literal>SHARE UPDATE EXCLUSIVE
</literal> lock on the
4331 partitioned table rather than the
<literal>ACCESS EXCLUSIVE
</literal>
4332 lock required by
<command>CREATE TABLE ... PARTITION OF
</command>,
4333 so it is more friendly to concurrent operations on the partitioned table;
4334 see
<link linkend=
"sql-altertable-attach-partition"><literal>ALTER TABLE ... ATTACH PARTITION
</literal></link>
4335 for additional details. The
4336 <link linkend=
"sql-createtable-parms-like"><literal>CREATE TABLE ... LIKE
</literal></link>
4337 option can be helpful to avoid tediously repeating the parent table's
4338 definition; for example:
4341 CREATE TABLE measurement_y2008m02
4342 (LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS)
4343 TABLESPACE fasttablespace;
4345 ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
4346 CHECK ( logdate
>= DATE '
2008-
02-
01' AND logdate
< DATE '
2008-
03-
01' );
4348 \copy measurement_y2008m02 from 'measurement_y2008m02'
4349 -- possibly some other data preparation work
4351 ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02
4352 FOR VALUES FROM ('
2008-
02-
01') TO ('
2008-
03-
01' );
4357 Note that when running the
<command>ATTACH PARTITION
</command> command,
4358 the table will be scanned to validate the partition constraint while
4359 holding an
<literal>ACCESS EXCLUSIVE
</literal> lock on that partition.
4360 As shown above, it is recommended to avoid this scan by creating a
4361 <literal>CHECK
</literal> constraint matching the expected partition
4362 constraint on the table prior to attaching it. Once the
4363 <command>ATTACH PARTITION
</command> is complete, it is recommended to drop
4364 the now-redundant
<literal>CHECK
</literal> constraint.
4365 If the table being attached is itself a partitioned table, then each of its
4366 sub-partitions will be recursively locked and scanned until either a
4367 suitable
<literal>CHECK
</literal> constraint is encountered or the leaf
4368 partitions are reached.
4372 Similarly, if the partitioned table has a
<literal>DEFAULT
</literal>
4373 partition, it is recommended to create a
<literal>CHECK
</literal>
4374 constraint which excludes the to-be-attached partition's constraint. If
4375 this is not done, the
<literal>DEFAULT
</literal> partition will be
4376 scanned to verify that it contains no records which should be located in
4377 the partition being attached. This operation will be performed whilst
4378 holding an
<literal>ACCESS EXCLUSIVE
</literal> lock on the
<literal>
4379 DEFAULT
</literal> partition. If the
<literal>DEFAULT
</literal> partition
4380 is itself a partitioned table, then each of its partitions will be
4381 recursively checked in the same way as the table being attached, as
4386 As mentioned earlier, it is possible to create indexes on partitioned
4387 tables so that they are applied automatically to the entire hierarchy.
4388 This can be very convenient as not only will all existing partitions be
4389 indexed, but any future partitions will be as well. However, one
4390 limitation when creating new indexes on partitioned tables is that it
4391 is not possible to use the
<literal>CONCURRENTLY
</literal>
4392 qualifier, which could lead to long lock times. To avoid this, you can
4393 use
<command>CREATE INDEX ON ONLY
</command> the partitioned table, which
4394 creates the new index marked as invalid, preventing automatic application
4395 to existing partitions. Instead, indexes can then be created individually
4396 on each partition using
<literal>CONCURRENTLY
</literal> and
4397 <firstterm>attached
</firstterm> to the partitioned index on the parent
4398 using
<command>ALTER INDEX ... ATTACH PARTITION
</command>. Once indexes for
4399 all the partitions are attached to the parent index, the parent index will
4400 be marked valid automatically. Example:
4402 CREATE INDEX measurement_usls_idx ON ONLY measurement (unitsales);
4404 CREATE INDEX CONCURRENTLY measurement_usls_200602_idx
4405 ON measurement_y2006m02 (unitsales);
4406 ALTER INDEX measurement_usls_idx
4407 ATTACH PARTITION measurement_usls_200602_idx;
4411 This technique can be used with
<literal>UNIQUE
</literal> and
4412 <literal>PRIMARY KEY
</literal> constraints too; the indexes are created
4413 implicitly when the constraint is created. Example:
4415 ALTER TABLE ONLY measurement ADD UNIQUE (city_id, logdate);
4417 ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
4418 ALTER INDEX measurement_city_id_logdate_key
4419 ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
4425 <sect3 id=
"ddl-partitioning-declarative-limitations">
4426 <title>Limitations
</title>
4429 The following limitations apply to partitioned tables:
4433 To create a unique or primary key constraint on a partitioned table,
4434 the partition keys must not include any expressions or function calls
4435 and the constraint's columns must include all of the partition key
4436 columns. This limitation exists because the individual indexes making
4437 up the constraint can only directly enforce uniqueness within their own
4438 partitions; therefore, the partition structure itself must guarantee
4439 that there are not duplicates in different partitions.
4445 Similarly an exclusion constraint must include all the
4446 partition key columns. Furthermore the constraint must compare those
4447 columns for equality (not e.g.
<literal>&&</literal>).
4448 Again, this limitation stems from not being able to enforce
4449 cross-partition restrictions. The constraint may include additional
4450 columns that aren't part of the partition key, and it may compare
4451 those with any operators you like.
4457 <literal>BEFORE ROW
</literal> triggers on
<literal>INSERT
</literal>
4458 cannot change which partition is the final destination for a new row.
4464 Mixing temporary and permanent relations in the same partition tree is
4465 not allowed. Hence, if the partitioned table is permanent, so must be
4466 its partitions and likewise if the partitioned table is temporary. When
4467 using temporary relations, all members of the partition tree have to be
4468 from the same session.
4475 Individual partitions are linked to their partitioned table using
4476 inheritance behind-the-scenes. However, it is not possible to use
4477 all of the generic features of inheritance with declaratively
4478 partitioned tables or their partitions, as discussed below. Notably,
4479 a partition cannot have any parents other than the partitioned table
4480 it is a partition of, nor can a table inherit from both a partitioned
4481 table and a regular table. That means partitioned tables and their
4482 partitions never share an inheritance hierarchy with regular tables.
4486 Since a partition hierarchy consisting of the partitioned table and its
4487 partitions is still an inheritance hierarchy,
4488 <structfield>tableoid
</structfield> and all the normal rules of
4489 inheritance apply as described in
<xref linkend=
"ddl-inherit"/>, with
4495 Partitions cannot have columns that are not present in the parent. It
4496 is not possible to specify columns when creating partitions with
4497 <command>CREATE TABLE
</command>, nor is it possible to add columns to
4498 partitions after-the-fact using
<command>ALTER TABLE
</command>.
4499 Tables may be added as a partition with
<command>ALTER TABLE
4500 ... ATTACH PARTITION
</command> only if their columns exactly match
4507 Both
<literal>CHECK
</literal> and
<literal>NOT NULL
</literal>
4508 constraints of a partitioned table are always inherited by all its
4509 partitions; it is not allowed to create
<literal>NO INHERIT
</literal>
4510 constraints of those types.
4511 You cannot drop a constraint of those types if the same constraint
4512 is present in the parent table.
4518 Using
<literal>ONLY
</literal> to add or drop a constraint on only
4519 the partitioned table is supported as long as there are no
4520 partitions. Once partitions exist, using
<literal>ONLY
</literal>
4521 will result in an error for any constraints other than
4522 <literal>UNIQUE
</literal> and
<literal>PRIMARY KEY
</literal>.
4523 Instead, constraints on the partitions
4524 themselves can be added and (if they are not present in the parent
4531 As a partitioned table does not have any data itself, attempts to use
4532 <command>TRUNCATE
</command> <literal>ONLY
</literal> on a partitioned
4533 table will always return an error.
4541 <sect2 id=
"ddl-partitioning-using-inheritance">
4542 <title>Partitioning Using Inheritance
</title>
4545 While the built-in declarative partitioning is suitable for most
4546 common use cases, there are some circumstances where a more flexible
4547 approach may be useful. Partitioning can be implemented using table
4548 inheritance, which allows for several features not supported
4549 by declarative partitioning, such as:
4554 For declarative partitioning, partitions must have exactly the same set
4555 of columns as the partitioned table, whereas with table inheritance,
4556 child tables may have extra columns not present in the parent.
4562 Table inheritance allows for multiple inheritance.
4568 Declarative partitioning only supports range, list and hash
4569 partitioning, whereas table inheritance allows data to be divided in a
4570 manner of the user's choosing. (Note, however, that if constraint
4571 exclusion is unable to prune child tables effectively, query performance
4578 <sect3 id=
"ddl-partitioning-inheritance-example">
4579 <title>Example
</title>
4582 This example builds a partitioning structure equivalent to the
4583 declarative partitioning example above. Use
4584 the following steps:
4586 <orderedlist spacing=
"compact">
4589 Create the
<quote>root
</quote> table, from which all of the
4590 <quote>child
</quote> tables will inherit. This table will contain no data. Do not
4591 define any check constraints on this table, unless you intend them
4592 to be applied equally to all child tables. There is no point in
4593 defining any indexes or unique constraints on it, either. For our
4594 example, the root table is the
<structname>measurement
</structname>
4595 table as originally defined:
4598 CREATE TABLE measurement (
4599 city_id int not null,
4600 logdate date not null,
4610 Create several
<quote>child
</quote> tables that each inherit from
4611 the root table. Normally, these tables will not add any columns
4612 to the set inherited from the root. Just as with declarative
4613 partitioning, these tables are in every way normal
4614 <productname>PostgreSQL
</productname> tables (or foreign tables).
4619 CREATE TABLE measurement_y2006m02 () INHERITS (measurement);
4620 CREATE TABLE measurement_y2006m03 () INHERITS (measurement);
4622 CREATE TABLE measurement_y2007m11 () INHERITS (measurement);
4623 CREATE TABLE measurement_y2007m12 () INHERITS (measurement);
4624 CREATE TABLE measurement_y2008m01 () INHERITS (measurement);
4631 Add non-overlapping table constraints to the child tables to
4632 define the allowed key values in each.
4636 Typical examples would be:
4639 CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' ))
4640 CHECK ( outletID
>=
100 AND outletID
< 200 )
4642 Ensure that the constraints guarantee that there is no overlap
4643 between the key values permitted in different child tables. A common
4644 mistake is to set up range constraints like:
4646 CHECK ( outletID BETWEEN
100 AND
200 )
4647 CHECK ( outletID BETWEEN
200 AND
300 )
4649 This is wrong since it is not clear which child table the key
4650 value
200 belongs in.
4651 Instead, ranges should be defined in this style:
4654 CREATE TABLE measurement_y2006m02 (
4655 CHECK ( logdate
>= DATE '
2006-
02-
01' AND logdate
< DATE '
2006-
03-
01' )
4656 ) INHERITS (measurement);
4658 CREATE TABLE measurement_y2006m03 (
4659 CHECK ( logdate
>= DATE '
2006-
03-
01' AND logdate
< DATE '
2006-
04-
01' )
4660 ) INHERITS (measurement);
4663 CREATE TABLE measurement_y2007m11 (
4664 CHECK ( logdate
>= DATE '
2007-
11-
01' AND logdate
< DATE '
2007-
12-
01' )
4665 ) INHERITS (measurement);
4667 CREATE TABLE measurement_y2007m12 (
4668 CHECK ( logdate
>= DATE '
2007-
12-
01' AND logdate
< DATE '
2008-
01-
01' )
4669 ) INHERITS (measurement);
4671 CREATE TABLE measurement_y2008m01 (
4672 CHECK ( logdate
>= DATE '
2008-
01-
01' AND logdate
< DATE '
2008-
02-
01' )
4673 ) INHERITS (measurement);
4680 For each child table, create an index on the key column(s),
4681 as well as any other indexes you might want.
4683 CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate);
4684 CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate);
4685 CREATE INDEX measurement_y2007m11_logdate ON measurement_y2007m11 (logdate);
4686 CREATE INDEX measurement_y2007m12_logdate ON measurement_y2007m12 (logdate);
4687 CREATE INDEX measurement_y2008m01_logdate ON measurement_y2008m01 (logdate);
4694 We want our application to be able to say
<literal>INSERT INTO
4695 measurement ...
</literal> and have the data be redirected into the
4696 appropriate child table. We can arrange that by attaching
4697 a suitable trigger function to the root table.
4698 If data will be added only to the latest child, we can
4699 use a very simple trigger function:
4702 CREATE OR REPLACE FUNCTION measurement_insert_trigger()
4703 RETURNS TRIGGER AS $$
4705 INSERT INTO measurement_y2008m01 VALUES (NEW.*);
4714 After creating the function, we create a trigger which
4715 calls the trigger function:
4718 CREATE TRIGGER insert_measurement_trigger
4719 BEFORE INSERT ON measurement
4720 FOR EACH ROW EXECUTE FUNCTION measurement_insert_trigger();
4723 We must redefine the trigger function each month so that it always
4724 inserts into the current child table. The trigger definition does
4725 not need to be updated, however.
4729 We might want to insert data and have the server automatically
4730 locate the child table into which the row should be added. We
4731 could do this with a more complex trigger function, for example:
4734 CREATE OR REPLACE FUNCTION measurement_insert_trigger()
4735 RETURNS TRIGGER AS $$
4737 IF ( NEW.logdate
>= DATE '
2006-
02-
01' AND
4738 NEW.logdate
< DATE '
2006-
03-
01' ) THEN
4739 INSERT INTO measurement_y2006m02 VALUES (NEW.*);
4740 ELSIF ( NEW.logdate
>= DATE '
2006-
03-
01' AND
4741 NEW.logdate
< DATE '
2006-
04-
01' ) THEN
4742 INSERT INTO measurement_y2006m03 VALUES (NEW.*);
4744 ELSIF ( NEW.logdate
>= DATE '
2008-
01-
01' AND
4745 NEW.logdate
< DATE '
2008-
02-
01' ) THEN
4746 INSERT INTO measurement_y2008m01 VALUES (NEW.*);
4748 RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!';
4756 The trigger definition is the same as before.
4757 Note that each
<literal>IF
</literal> test must exactly match the
4758 <literal>CHECK
</literal> constraint for its child table.
4762 While this function is more complex than the single-month case,
4763 it doesn't need to be updated as often, since branches can be
4764 added in advance of being needed.
4769 In practice, it might be best to check the newest child first,
4770 if most inserts go into that child. For simplicity, we have
4771 shown the trigger's tests in the same order as in other parts
4777 A different approach to redirecting inserts into the appropriate
4778 child table is to set up rules, instead of a trigger, on the
4779 root table. For example:
4782 CREATE RULE measurement_insert_y2006m02 AS
4783 ON INSERT TO measurement WHERE
4784 ( logdate
>= DATE '
2006-
02-
01' AND logdate
< DATE '
2006-
03-
01' )
4786 INSERT INTO measurement_y2006m02 VALUES (NEW.*);
4788 CREATE RULE measurement_insert_y2008m01 AS
4789 ON INSERT TO measurement WHERE
4790 ( logdate
>= DATE '
2008-
01-
01' AND logdate
< DATE '
2008-
02-
01' )
4792 INSERT INTO measurement_y2008m01 VALUES (NEW.*);
4795 A rule has significantly more overhead than a trigger, but the
4796 overhead is paid once per query rather than once per row, so this
4797 method might be advantageous for bulk-insert situations. In most
4798 cases, however, the trigger method will offer better performance.
4802 Be aware that
<command>COPY
</command> ignores rules. If you want to
4803 use
<command>COPY
</command> to insert data, you'll need to copy into the
4804 correct child table rather than directly into the root.
<command>COPY
</command>
4805 does fire triggers, so you can use it normally if you use the trigger
4810 Another disadvantage of the rule approach is that there is no simple
4811 way to force an error if the set of rules doesn't cover the insertion
4812 date; the data will silently go into the root table instead.
4818 Ensure that the
<xref linkend=
"guc-constraint-exclusion"/>
4819 configuration parameter is not disabled in
4820 <filename>postgresql.conf
</filename>; otherwise
4821 child tables may be accessed unnecessarily.
4828 As we can see, a complex table hierarchy could require a
4829 substantial amount of DDL. In the above example we would be creating
4830 a new child table each month, so it might be wise to write a script that
4831 generates the required DDL automatically.
4835 <sect3 id=
"ddl-partitioning-inheritance-maintenance">
4836 <title>Maintenance for Inheritance Partitioning
</title>
4838 To remove old data quickly, simply drop the child table that is no longer
4841 DROP TABLE measurement_y2006m02;
4846 To remove the child table from the inheritance hierarchy table but retain access to
4847 it as a table in its own right:
4850 ALTER TABLE measurement_y2006m02 NO INHERIT measurement;
4855 To add a new child table to handle new data, create an empty child table
4856 just as the original children were created above:
4859 CREATE TABLE measurement_y2008m02 (
4860 CHECK ( logdate
>= DATE '
2008-
02-
01' AND logdate
< DATE '
2008-
03-
01' )
4861 ) INHERITS (measurement);
4864 Alternatively, one may want to create and populate the new child table
4865 before adding it to the table hierarchy. This could allow data to be
4866 loaded, checked, and transformed before being made visible to queries on
4870 CREATE TABLE measurement_y2008m02
4871 (LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS);
4872 ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
4873 CHECK ( logdate
>= DATE '
2008-
02-
01' AND logdate
< DATE '
2008-
03-
01' );
4874 \copy measurement_y2008m02 from 'measurement_y2008m02'
4875 -- possibly some other data preparation work
4876 ALTER TABLE measurement_y2008m02 INHERIT measurement;
4881 <sect3 id=
"ddl-partitioning-inheritance-caveats">
4882 <title>Caveats
</title>
4885 The following caveats apply to partitioning implemented using
4890 There is no automatic way to verify that all of the
4891 <literal>CHECK
</literal> constraints are mutually
4892 exclusive. It is safer to create code that generates
4893 child tables and creates and/or modifies associated objects than
4894 to write each by hand.
4900 Indexes and foreign key constraints apply to single tables and not
4901 to their inheritance children, hence they have some
4902 <link linkend=
"ddl-inherit-caveats">caveats
</link> to be aware of.
4908 The schemes shown here assume that the values of a row's key column(s)
4909 never change, or at least do not change enough to require it to move to another partition.
4910 An
<command>UPDATE
</command> that attempts
4911 to do that will fail because of the
<literal>CHECK
</literal> constraints.
4912 If you need to handle such cases, you can put suitable update triggers
4913 on the child tables, but it makes management of the structure
4914 much more complicated.
4920 Manual
<command>VACUUM
</command> and
<command>ANALYZE
</command>
4921 commands will automatically process all inheritance child tables. If
4922 this is undesirable, you can use the
<literal>ONLY
</literal> keyword.
4925 ANALYZE ONLY measurement;
4927 will only process the root table.
4933 <command>INSERT
</command> statements with
<literal>ON CONFLICT
</literal>
4934 clauses are unlikely to work as expected, as the
<literal>ON CONFLICT
</literal>
4935 action is only taken in case of unique violations on the specified
4936 target relation, not its child relations.
4942 Triggers or rules will be needed to route rows to the desired
4943 child table, unless the application is explicitly aware of the
4944 partitioning scheme. Triggers may be complicated to write, and will
4945 be much slower than the tuple routing performed internally by
4946 declarative partitioning.
4954 <sect2 id=
"ddl-partition-pruning">
4955 <title>Partition Pruning
</title>
4958 <primary>partition pruning
</primary>
4962 <firstterm>Partition pruning
</firstterm> is a query optimization technique
4963 that improves performance for declaratively partitioned tables.
4967 SET enable_partition_pruning = on; -- the default
4968 SELECT count(*) FROM measurement WHERE logdate
>= DATE '
2008-
01-
01';
4971 Without partition pruning, the above query would scan each of the
4972 partitions of the
<structname>measurement
</structname> table. With
4973 partition pruning enabled, the planner will examine the definition
4974 of each partition and prove that the partition need not
4975 be scanned because it could not contain any rows meeting the query's
4976 <literal>WHERE
</literal> clause. When the planner can prove this, it
4977 excludes (
<firstterm>prunes
</firstterm>) the partition from the query
4982 By using the EXPLAIN command and the
<xref
4983 linkend=
"guc-enable-partition-pruning"/> configuration parameter, it's
4984 possible to show the difference between a plan for which partitions have
4985 been pruned and one for which they have not. A typical unoptimized
4986 plan for this type of table setup is:
4988 SET enable_partition_pruning = off;
4989 EXPLAIN SELECT count(*) FROM measurement WHERE logdate
>= DATE '
2008-
01-
01';
4991 -------------------------------------------------------------------
&zwsp;----------------
4992 Aggregate (cost=
188.76.
.188.77 rows=
1 width=
8)
4993 -
> Append (cost=
0.00.
.181.05 rows=
3085 width=
0)
4994 -
> Seq Scan on measurement_y2006m02 (cost=
0.00.
.33.12 rows=
617 width=
0)
4995 Filter: (logdate
>= '
2008-
01-
01'::date)
4996 -
> Seq Scan on measurement_y2006m03 (cost=
0.00.
.33.12 rows=
617 width=
0)
4997 Filter: (logdate
>= '
2008-
01-
01'::date)
4999 -
> Seq Scan on measurement_y2007m11 (cost=
0.00.
.33.12 rows=
617 width=
0)
5000 Filter: (logdate
>= '
2008-
01-
01'::date)
5001 -
> Seq Scan on measurement_y2007m12 (cost=
0.00.
.33.12 rows=
617 width=
0)
5002 Filter: (logdate
>= '
2008-
01-
01'::date)
5003 -
> Seq Scan on measurement_y2008m01 (cost=
0.00.
.33.12 rows=
617 width=
0)
5004 Filter: (logdate
>= '
2008-
01-
01'::date)
5007 Some or all of the partitions might use index scans instead of
5008 full-table sequential scans, but the point here is that there
5009 is no need to scan the older partitions at all to answer this query.
5010 When we enable partition pruning, we get a significantly
5011 cheaper plan that will deliver the same answer:
5013 SET enable_partition_pruning = on;
5014 EXPLAIN SELECT count(*) FROM measurement WHERE logdate
>= DATE '
2008-
01-
01';
5016 -------------------------------------------------------------------
&zwsp;----------------
5017 Aggregate (cost=
37.75.
.37.76 rows=
1 width=
8)
5018 -
> Seq Scan on measurement_y2008m01 (cost=
0.00.
.33.12 rows=
617 width=
0)
5019 Filter: (logdate
>= '
2008-
01-
01'::date)
5024 Note that partition pruning is driven only by the constraints defined
5025 implicitly by the partition keys, not by the presence of indexes.
5026 Therefore it isn't necessary to define indexes on the key columns.
5027 Whether an index needs to be created for a given partition depends on
5028 whether you expect that queries that scan the partition will
5029 generally scan a large part of the partition or just a small part.
5030 An index will be helpful in the latter case but not the former.
5034 Partition pruning can be performed not only during the planning of a
5035 given query, but also during its execution. This is useful as it can
5036 allow more partitions to be pruned when clauses contain expressions
5037 whose values are not known at query planning time, for example,
5038 parameters defined in a
<command>PREPARE
</command> statement, using a
5039 value obtained from a subquery, or using a parameterized value on the
5040 inner side of a nested loop join. Partition pruning during execution
5041 can be performed at any of the following times:
5046 During initialization of the query plan. Partition pruning can be
5047 performed here for parameter values which are known during the
5048 initialization phase of execution. Partitions which are pruned
5049 during this stage will not show up in the query's
5050 <command>EXPLAIN
</command> or
<command>EXPLAIN ANALYZE
</command>.
5051 It is possible to determine the number of partitions which were
5052 removed during this phase by observing the
5053 <quote>Subplans Removed
</quote> property in the
5054 <command>EXPLAIN
</command> output.
5060 During actual execution of the query plan. Partition pruning may
5061 also be performed here to remove partitions using values which are
5062 only known during actual query execution. This includes values
5063 from subqueries and values from execution-time parameters such as
5064 those from parameterized nested loop joins. Since the value of
5065 these parameters may change many times during the execution of the
5066 query, partition pruning is performed whenever one of the
5067 execution parameters being used by partition pruning changes.
5068 Determining if partitions were pruned during this phase requires
5069 careful inspection of the
<literal>loops
</literal> property in
5070 the
<command>EXPLAIN ANALYZE
</command> output. Subplans
5071 corresponding to different partitions may have different values
5072 for it depending on how many times each of them was pruned during
5073 execution. Some may be shown as
<literal>(never executed)
</literal>
5074 if they were pruned every time.
5081 Partition pruning can be disabled using the
5082 <xref linkend=
"guc-enable-partition-pruning"/> setting.
5086 <sect2 id=
"ddl-partitioning-constraint-exclusion">
5087 <title>Partitioning and Constraint Exclusion
</title>
5090 <primary>constraint exclusion
</primary>
5094 <firstterm>Constraint exclusion
</firstterm> is a query optimization
5095 technique similar to partition pruning. While it is primarily used
5096 for partitioning implemented using the legacy inheritance method, it can be
5097 used for other purposes, including with declarative partitioning.
5101 Constraint exclusion works in a very similar way to partition
5102 pruning, except that it uses each table's
<literal>CHECK
</literal>
5103 constraints
— which gives it its name
— whereas partition
5104 pruning uses the table's partition bounds, which exist only in the
5105 case of declarative partitioning. Another difference is that
5106 constraint exclusion is only applied at plan time; there is no attempt
5107 to remove partitions at execution time.
5111 The fact that constraint exclusion uses
<literal>CHECK
</literal>
5112 constraints, which makes it slow compared to partition pruning, can
5113 sometimes be used as an advantage: because constraints can be defined
5114 even on declaratively-partitioned tables, in addition to their internal
5115 partition bounds, constraint exclusion may be able
5116 to elide additional partitions from the query plan.
5120 The default (and recommended) setting of
5121 <xref linkend=
"guc-constraint-exclusion"/> is neither
5122 <literal>on
</literal> nor
<literal>off
</literal>, but an intermediate setting
5123 called
<literal>partition
</literal>, which causes the technique to be
5124 applied only to queries that are likely to be working on inheritance partitioned
5125 tables. The
<literal>on
</literal> setting causes the planner to examine
5126 <literal>CHECK
</literal> constraints in all queries, even simple ones that
5127 are unlikely to benefit.
5131 The following caveats apply to constraint exclusion:
5136 Constraint exclusion is only applied during query planning, unlike
5137 partition pruning, which can also be applied during query execution.
5143 Constraint exclusion only works when the query's
<literal>WHERE
</literal>
5144 clause contains constants (or externally supplied parameters).
5145 For example, a comparison against a non-immutable function such as
5146 <function>CURRENT_TIMESTAMP
</function> cannot be optimized, since the
5147 planner cannot know which child table the function's value might fall
5154 Keep the partitioning constraints simple, else the planner may not be
5155 able to prove that child tables might not need to be visited. Use simple
5156 equality conditions for list partitioning, or simple
5157 range tests for range partitioning, as illustrated in the preceding
5158 examples. A good rule of thumb is that partitioning constraints should
5159 contain only comparisons of the partitioning column(s) to constants
5160 using B-tree-indexable operators, because only B-tree-indexable
5161 column(s) are allowed in the partition key.
5167 All constraints on all children of the parent table are examined
5168 during constraint exclusion, so large numbers of children are likely
5169 to increase query planning time considerably. So the legacy
5170 inheritance based partitioning will work well with up to perhaps a
5171 hundred child tables; don't try to use many thousands of children.
5179 <sect2 id=
"ddl-partitioning-declarative-best-practices">
5180 <title>Best Practices for Declarative Partitioning
</title>
5183 The choice of how to partition a table should be made carefully, as the
5184 performance of query planning and execution can be negatively affected by
5189 One of the most critical design decisions will be the column or columns
5190 by which you partition your data. Often the best choice will be to
5191 partition by the column or set of columns which most commonly appear in
5192 <literal>WHERE
</literal> clauses of queries being executed on the
5193 partitioned table.
<literal>WHERE
</literal> clauses that are compatible
5194 with the partition bound constraints can be used to prune unneeded
5195 partitions. However, you may be forced into making other decisions by
5196 requirements for the
<literal>PRIMARY KEY
</literal> or a
5197 <literal>UNIQUE
</literal> constraint. Removal of unwanted data is also a
5198 factor to consider when planning your partitioning strategy. An entire
5199 partition can be detached fairly quickly, so it may be beneficial to
5200 design the partition strategy in such a way that all data to be removed
5201 at once is located in a single partition.
5205 Choosing the target number of partitions that the table should be divided
5206 into is also a critical decision to make. Not having enough partitions
5207 may mean that indexes remain too large and that data locality remains poor
5208 which could result in low cache hit ratios. However, dividing the table
5209 into too many partitions can also cause issues. Too many partitions can
5210 mean longer query planning times and higher memory consumption during both
5211 query planning and execution, as further described below.
5212 When choosing how to partition your table,
5213 it's also important to consider what changes may occur in the future. For
5214 example, if you choose to have one partition per customer and you
5215 currently have a small number of large customers, consider the
5216 implications if in several years you instead find yourself with a large
5217 number of small customers. In this case, it may be better to choose to
5218 partition by
<literal>HASH
</literal> and choose a reasonable number of
5219 partitions rather than trying to partition by
<literal>LIST
</literal> and
5220 hoping that the number of customers does not increase beyond what it is
5221 practical to partition the data by.
5225 Sub-partitioning can be useful to further divide partitions that are
5226 expected to become larger than other partitions.
5227 Another option is to use range partitioning with multiple columns in
5229 Either of these can easily lead to excessive numbers of partitions,
5230 so restraint is advisable.
5234 It is important to consider the overhead of partitioning during
5235 query planning and execution. The query planner is generally able to
5236 handle partition hierarchies with up to a few thousand partitions fairly
5237 well, provided that typical queries allow the query planner to prune all
5238 but a small number of partitions. Planning times become longer and memory
5239 consumption becomes higher when more partitions remain after the planner
5240 performs partition pruning. Another
5241 reason to be concerned about having a large number of partitions is that
5242 the server's memory consumption may grow significantly over
5243 time, especially if many sessions touch large numbers of partitions.
5244 That's because each partition requires its metadata to be loaded into the
5245 local memory of each session that touches it.
5249 With data warehouse type workloads, it can make sense to use a larger
5250 number of partitions than with an
<acronym>OLTP
</acronym> type workload.
5251 Generally, in data warehouses, query planning time is less of a concern as
5252 the majority of processing time is spent during query execution. With
5253 either of these two types of workload, it is important to make the right
5254 decisions early, as re-partitioning large quantities of data can be
5255 painfully slow. Simulations of the intended workload are often beneficial
5256 for optimizing the partitioning strategy. Never just assume that more
5257 partitions are better than fewer partitions, nor vice-versa.
5263 <sect1 id=
"ddl-foreign-data">
5264 <title>Foreign Data
</title>
5267 <primary>foreign data
</primary>
5270 <primary>foreign table
</primary>
5273 <primary>user mapping
</primary>
5277 <productname>PostgreSQL
</productname> implements portions of the SQL/MED
5278 specification, allowing you to access data that resides outside
5279 PostgreSQL using regular SQL queries. Such data is referred to as
5280 <firstterm>foreign data
</firstterm>. (Note that this usage is not to be confused
5281 with foreign keys, which are a type of constraint within the database.)
5285 Foreign data is accessed with help from a
5286 <firstterm>foreign data wrapper
</firstterm>. A foreign data wrapper is a
5287 library that can communicate with an external data source, hiding the
5288 details of connecting to the data source and obtaining data from it.
5289 There are some foreign data wrappers available as
<filename>contrib
</filename>
5290 modules; see
<xref linkend=
"contrib"/>. Other kinds of foreign data
5291 wrappers might be found as third party products. If none of the existing
5292 foreign data wrappers suit your needs, you can write your own; see
<xref
5293 linkend=
"fdwhandler"/>.
5297 To access foreign data, you need to create a
<firstterm>foreign server
</firstterm>
5298 object, which defines how to connect to a particular external data source
5299 according to the set of options used by its supporting foreign data
5300 wrapper. Then you need to create one or more
<firstterm>foreign
5301 tables
</firstterm>, which define the structure of the remote data. A
5302 foreign table can be used in queries just like a normal table, but a
5303 foreign table has no storage in the PostgreSQL server. Whenever it is
5304 used,
<productname>PostgreSQL
</productname> asks the foreign data wrapper
5305 to fetch data from the external source, or transmit data to the external
5306 source in the case of update commands.
5310 Accessing remote data may require authenticating to the external
5311 data source. This information can be provided by a
5312 <firstterm>user mapping
</firstterm>, which can provide additional data
5313 such as user names and passwords based
5314 on the current
<productname>PostgreSQL
</productname> role.
5318 For additional information, see
5319 <xref linkend=
"sql-createforeigndatawrapper"/>,
5320 <xref linkend=
"sql-createserver"/>,
5321 <xref linkend=
"sql-createusermapping"/>,
5322 <xref linkend=
"sql-createforeigntable"/>, and
5323 <xref linkend=
"sql-importforeignschema"/>.
5327 <sect1 id=
"ddl-others">
5328 <title>Other Database Objects
</title>
5331 Tables are the central objects in a relational database structure,
5332 because they hold your data. But they are not the only objects
5333 that exist in a database. Many other kinds of objects can be
5334 created to make the use and management of the data more efficient
5335 or convenient. They are not discussed in this chapter, but we give
5336 you a list here so that you are aware of what is possible:
5348 Functions, procedures, and operators
5354 Data types and domains
5360 Triggers and rewrite rules
5366 Detailed information on
5367 these topics appears in
<xref linkend=
"server-programming"/>.
5371 <sect1 id=
"ddl-depend">
5372 <title>Dependency Tracking
</title>
5374 <indexterm zone=
"ddl-depend">
5375 <primary>CASCADE
</primary>
5376 <secondary sortas=
"DROP">with DROP
</secondary>
5379 <indexterm zone=
"ddl-depend">
5380 <primary>RESTRICT
</primary>
5381 <secondary sortas=
"DROP">with DROP
</secondary>
5385 When you create complex database structures involving many tables
5386 with foreign key constraints, views, triggers, functions, etc. you
5387 implicitly create a net of dependencies between the objects.
5388 For instance, a table with a foreign key constraint depends on the
5389 table it references.
5393 To ensure the integrity of the entire database structure,
5394 <productname>PostgreSQL
</productname> makes sure that you cannot
5395 drop objects that other objects still depend on. For example,
5396 attempting to drop the products table we considered in
<xref
5397 linkend=
"ddl-constraints-fk"/>, with the orders table depending on
5398 it, would result in an error message like this:
5400 DROP TABLE products;
5402 ERROR: cannot drop table products because other objects depend on it
5403 DETAIL: constraint orders_product_no_fkey on table orders depends on table products
5404 HINT: Use DROP ... CASCADE to drop the dependent objects too.
5406 The error message contains a useful hint: if you do not want to
5407 bother deleting all the dependent objects individually, you can run:
5409 DROP TABLE products CASCADE;
5411 and all the dependent objects will be removed, as will any objects
5412 that depend on them, recursively. In this case, it doesn't remove
5413 the orders table, it only removes the foreign key constraint.
5414 It stops there because nothing depends on the foreign key constraint.
5415 (If you want to check what
<command>DROP ... CASCADE
</command> will do,
5416 run
<command>DROP
</command> without
<literal>CASCADE
</literal> and read the
5417 <literal>DETAIL
</literal> output.)
5421 Almost all
<command>DROP
</command> commands in
<productname>PostgreSQL
</productname> support
5422 specifying
<literal>CASCADE
</literal>. Of course, the nature of
5423 the possible dependencies varies with the type of the object. You
5424 can also write
<literal>RESTRICT
</literal> instead of
5425 <literal>CASCADE
</literal> to get the default behavior, which is to
5426 prevent dropping objects that any other objects depend on.
5431 According to the SQL standard, specifying either
5432 <literal>RESTRICT
</literal> or
<literal>CASCADE
</literal> is
5433 required in a
<command>DROP
</command> command. No database system actually
5434 enforces that rule, but whether the default behavior
5435 is
<literal>RESTRICT
</literal> or
<literal>CASCADE
</literal> varies
5441 If a
<command>DROP
</command> command lists multiple
5442 objects,
<literal>CASCADE
</literal> is only required when there are
5443 dependencies outside the specified group. For example, when saying
5444 <literal>DROP TABLE tab1, tab2
</literal> the existence of a foreign
5445 key referencing
<literal>tab1
</literal> from
<literal>tab2
</literal> would not mean
5446 that
<literal>CASCADE
</literal> is needed to succeed.
5450 For a user-defined function or procedure whose body is defined as a string
5451 literal,
<productname>PostgreSQL
</productname> tracks
5452 dependencies associated with the function's externally-visible properties,
5453 such as its argument and result types, but
<emphasis>not
</emphasis> dependencies
5454 that could only be known by examining the function body. As an example,
5455 consider this situation:
5458 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow',
5459 'green', 'blue', 'purple');
5461 CREATE TABLE my_colors (color rainbow, note text);
5463 CREATE FUNCTION get_color_note (rainbow) RETURNS text AS
5464 'SELECT note FROM my_colors WHERE color = $
1'
5468 (See
<xref linkend=
"xfunc-sql"/> for an explanation of SQL-language
5469 functions.)
<productname>PostgreSQL
</productname> will be aware that
5470 the
<function>get_color_note
</function> function depends on the
<type>rainbow
</type>
5471 type: dropping the type would force dropping the function, because its
5472 argument type would no longer be defined. But
<productname>PostgreSQL
</productname>
5473 will not consider
<function>get_color_note
</function> to depend on
5474 the
<structname>my_colors
</structname> table, and so will not drop the function if
5475 the table is dropped. While there are disadvantages to this approach,
5476 there are also benefits. The function is still valid in some sense if the
5477 table is missing, though executing it would cause an error; creating a new
5478 table of the same name would allow the function to work again.
5482 On the other hand, for an SQL-language function or procedure whose body
5483 is written in SQL-standard style, the body is parsed at function
5484 definition time and all dependencies recognized by the parser are
5485 stored. Thus, if we write the function above as
5488 CREATE FUNCTION get_color_note (rainbow) RETURNS text
5490 SELECT note FROM my_colors WHERE color = $
1;
5494 then the function's dependency on the
<structname>my_colors
</structname>
5495 table will be known and enforced by
<command>DROP
</command>.