4 5.5.1. Check Constraints
5 5.5.2. Not-Null Constraints
6 5.5.3. Unique Constraints
9 5.5.6. Exclusion Constraints
11 Data types are a way to limit the kind of data that can be stored in a
12 table. For many applications, however, the constraint they provide is
13 too coarse. For example, a column containing a product price should
14 probably only accept positive values. But there is no standard data
15 type that accepts only positive numbers. Another issue is that you
16 might want to constrain column data with respect to other columns or
17 rows. For example, in a table containing product information, there
18 should be only one row for each product number.
20 To that end, SQL allows you to define constraints on columns and
21 tables. Constraints give you as much control over the data in your
22 tables as you wish. If a user attempts to store data in a column that
23 would violate a constraint, an error is raised. This applies even if
24 the value came from the default value definition.
26 5.5.1. Check Constraints #
28 A check constraint is the most generic constraint type. It allows you
29 to specify that the value in a certain column must satisfy a Boolean
30 (truth-value) expression. For instance, to require positive product
31 prices, you could use:
32 CREATE TABLE products (
35 price numeric CHECK (price > 0)
38 As you see, the constraint definition comes after the data type, just
39 like default value definitions. Default values and constraints can be
40 listed in any order. A check constraint consists of the key word CHECK
41 followed by an expression in parentheses. The check constraint
42 expression should involve the column thus constrained, otherwise the
43 constraint would not make too much sense.
45 You can also give the constraint a separate name. This clarifies error
46 messages and allows you to refer to the constraint when you need to
47 change it. The syntax is:
48 CREATE TABLE products (
51 price numeric CONSTRAINT positive_price CHECK (price > 0)
54 So, to specify a named constraint, use the key word CONSTRAINT followed
55 by an identifier followed by the constraint definition. (If you don't
56 specify a constraint name in this way, the system chooses a name for
59 A check constraint can also refer to several columns. Say you store a
60 regular price and a discounted price, and you want to ensure that the
61 discounted price is lower than the regular price:
62 CREATE TABLE products (
65 price numeric CHECK (price > 0),
66 discounted_price numeric CHECK (discounted_price > 0),
67 CHECK (price > discounted_price)
70 The first two constraints should look familiar. The third one uses a
71 new syntax. It is not attached to a particular column, instead it
72 appears as a separate item in the comma-separated column list. Column
73 definitions and these constraint definitions can be listed in mixed
76 We say that the first two constraints are column constraints, whereas
77 the third one is a table constraint because it is written separately
78 from any one column definition. Column constraints can also be written
79 as table constraints, while the reverse is not necessarily possible,
80 since a column constraint is supposed to refer to only the column it is
81 attached to. (PostgreSQL doesn't enforce that rule, but you should
82 follow it if you want your table definitions to work with other
83 database systems.) The above example could also be written as:
84 CREATE TABLE products (
89 discounted_price numeric,
90 CHECK (discounted_price > 0),
91 CHECK (price > discounted_price)
95 CREATE TABLE products (
98 price numeric CHECK (price > 0),
99 discounted_price numeric,
100 CHECK (discounted_price > 0 AND price > discounted_price)
103 It's a matter of taste.
105 Names can be assigned to table constraints in the same way as column
107 CREATE TABLE products (
112 discounted_price numeric,
113 CHECK (discounted_price > 0),
114 CONSTRAINT valid_discount CHECK (price > discounted_price)
117 It should be noted that a check constraint is satisfied if the check
118 expression evaluates to true or the null value. Since most expressions
119 will evaluate to the null value if any operand is null, they will not
120 prevent null values in the constrained columns. To ensure that a column
121 does not contain null values, the not-null constraint described in the
122 next section can be used.
126 PostgreSQL does not support CHECK constraints that reference table data
127 other than the new or updated row being checked. While a CHECK
128 constraint that violates this rule may appear to work in simple tests,
129 it cannot guarantee that the database will not reach a state in which
130 the constraint condition is false (due to subsequent changes of the
131 other row(s) involved). This would cause a database dump and restore to
132 fail. The restore could fail even when the complete database state is
133 consistent with the constraint, due to rows not being loaded in an
134 order that will satisfy the constraint. If possible, use UNIQUE,
135 EXCLUDE, or FOREIGN KEY constraints to express cross-row and
136 cross-table restrictions.
138 If what you desire is a one-time check against other rows at row
139 insertion, rather than a continuously-maintained consistency guarantee,
140 a custom trigger can be used to implement that. (This approach avoids
141 the dump/restore problem because pg_dump does not reinstall triggers
142 until after restoring data, so that the check will not be enforced
143 during a dump/restore.)
147 PostgreSQL assumes that CHECK constraints' conditions are immutable,
148 that is, they will always give the same result for the same input row.
149 This assumption is what justifies examining CHECK constraints only when
150 rows are inserted or updated, and not at other times. (The warning
151 above about not referencing other table data is really a special case
152 of this restriction.)
154 An example of a common way to break this assumption is to reference a
155 user-defined function in a CHECK expression, and then change the
156 behavior of that function. PostgreSQL does not disallow that, but it
157 will not notice if there are rows in the table that now violate the
158 CHECK constraint. That would cause a subsequent database dump and
159 restore to fail. The recommended way to handle such a change is to drop
160 the constraint (using ALTER TABLE), adjust the function definition, and
161 re-add the constraint, thereby rechecking it against all table rows.
163 5.5.2. Not-Null Constraints #
165 A not-null constraint simply specifies that a column must not assume
166 the null value. A syntax example:
167 CREATE TABLE products (
168 product_no integer NOT NULL,
173 An explicit constraint name can also be specified, for example:
174 CREATE TABLE products (
175 product_no integer NOT NULL,
176 name text CONSTRAINT products_name_not_null NOT NULL,
180 A not-null constraint is usually written as a column constraint. The
181 syntax for writing it as a table constraint is
182 CREATE TABLE products (
190 But this syntax is not standard and mainly intended for use by pg_dump.
192 A not-null constraint is functionally equivalent to creating a check
193 constraint CHECK (column_name IS NOT NULL), but in PostgreSQL creating
194 an explicit not-null constraint is more efficient.
196 Of course, a column can have more than one constraint. Just write the
197 constraints one after another:
198 CREATE TABLE products (
199 product_no integer NOT NULL,
201 price numeric NOT NULL CHECK (price > 0)
204 The order doesn't matter. It does not necessarily determine in which
205 order the constraints are checked.
207 However, a column can have at most one explicit not-null constraint.
209 The NOT NULL constraint has an inverse: the NULL constraint. This does
210 not mean that the column must be null, which would surely be useless.
211 Instead, this simply selects the default behavior that the column might
212 be null. The NULL constraint is not present in the SQL standard and
213 should not be used in portable applications. (It was only added to
214 PostgreSQL to be compatible with some other database systems.) Some
215 users, however, like it because it makes it easy to toggle the
216 constraint in a script file. For example, you could start with:
217 CREATE TABLE products (
218 product_no integer NULL,
223 and then insert the NOT key word where desired.
227 In most database designs the majority of columns should be marked not
230 5.5.3. Unique Constraints #
232 Unique constraints ensure that the data contained in a column, or a
233 group of columns, is unique among all the rows in the table. The syntax
235 CREATE TABLE products (
236 product_no integer UNIQUE,
241 when written as a column constraint, and:
242 CREATE TABLE products (
249 when written as a table constraint.
251 To define a unique constraint for a group of columns, write it as a
252 table constraint with the column names separated by commas:
253 CREATE TABLE example (
260 This specifies that the combination of values in the indicated columns
261 is unique across the whole table, though any one of the columns need
262 not be (and ordinarily isn't) unique.
264 You can assign your own name for a unique constraint, in the usual way:
265 CREATE TABLE products (
266 product_no integer CONSTRAINT must_be_different UNIQUE,
271 Adding a unique constraint will automatically create a unique B-tree
272 index on the column or group of columns listed in the constraint. A
273 uniqueness restriction covering only some rows cannot be written as a
274 unique constraint, but it is possible to enforce such a restriction by
275 creating a unique partial index.
277 In general, a unique constraint is violated if there is more than one
278 row in the table where the values of all of the columns included in the
279 constraint are equal. By default, two null values are not considered
280 equal in this comparison. That means even in the presence of a unique
281 constraint it is possible to store duplicate rows that contain a null
282 value in at least one of the constrained columns. This behavior can be
283 changed by adding the clause NULLS NOT DISTINCT, like
284 CREATE TABLE products (
285 product_no integer UNIQUE NULLS NOT DISTINCT,
291 CREATE TABLE products (
295 UNIQUE NULLS NOT DISTINCT (product_no)
298 The default behavior can be specified explicitly using NULLS DISTINCT.
299 The default null treatment in unique constraints is
300 implementation-defined according to the SQL standard, and other
301 implementations have a different behavior. So be careful when
302 developing applications that are intended to be portable.
304 5.5.4. Primary Keys #
306 A primary key constraint indicates that a column, or group of columns,
307 can be used as a unique identifier for rows in the table. This requires
308 that the values be both unique and not null. So, the following two
309 table definitions accept the same data:
310 CREATE TABLE products (
311 product_no integer UNIQUE NOT NULL,
316 CREATE TABLE products (
317 product_no integer PRIMARY KEY,
322 Primary keys can span more than one column; the syntax is similar to
324 CREATE TABLE example (
331 Adding a primary key will automatically create a unique B-tree index on
332 the column or group of columns listed in the primary key, and will
333 force the column(s) to be marked NOT NULL.
335 A table can have at most one primary key. (There can be any number of
336 unique constraints, which combined with not-null constraints are
337 functionally almost the same thing, but only one can be identified as
338 the primary key.) Relational database theory dictates that every table
339 must have a primary key. This rule is not enforced by PostgreSQL, but
340 it is usually best to follow it.
342 Primary keys are useful both for documentation purposes and for client
343 applications. For example, a GUI application that allows modifying row
344 values probably needs to know the primary key of a table to be able to
345 identify rows uniquely. There are also various ways in which the
346 database system makes use of a primary key if one has been declared;
347 for example, the primary key defines the default target column(s) for
348 foreign keys referencing its table.
350 5.5.5. Foreign Keys #
352 A foreign key constraint specifies that the values in a column (or a
353 group of columns) must match the values appearing in some row of
354 another table. We say this maintains the referential integrity between
357 Say you have the product table that we have used several times already:
358 CREATE TABLE products (
359 product_no integer PRIMARY KEY,
364 Let's also assume you have a table storing orders of those products. We
365 want to ensure that the orders table only contains orders of products
366 that actually exist. So we define a foreign key constraint in the
367 orders table that references the products table:
368 CREATE TABLE orders (
369 order_id integer PRIMARY KEY,
370 product_no integer REFERENCES products (product_no),
374 Now it is impossible to create orders with non-NULL product_no entries
375 that do not appear in the products table.
377 We say that in this situation the orders table is the referencing table
378 and the products table is the referenced table. Similarly, there are
379 referencing and referenced columns.
381 You can also shorten the above command to:
382 CREATE TABLE orders (
383 order_id integer PRIMARY KEY,
384 product_no integer REFERENCES products,
388 because in absence of a column list the primary key of the referenced
389 table is used as the referenced column(s).
391 You can assign your own name for a foreign key constraint, in the usual
394 A foreign key can also constrain and reference a group of columns. As
395 usual, it then needs to be written in table constraint form. Here is a
396 contrived syntax example:
398 a integer PRIMARY KEY,
401 FOREIGN KEY (b, c) REFERENCES other_table (c1, c2)
404 Of course, the number and type of the constrained columns need to match
405 the number and type of the referenced columns.
407 Sometimes it is useful for the “other table” of a foreign key
408 constraint to be the same table; this is called a self-referential
409 foreign key. For example, if you want rows of a table to represent
410 nodes of a tree structure, you could write
412 node_id integer PRIMARY KEY,
413 parent_id integer REFERENCES tree,
418 A top-level node would have NULL parent_id, while non-NULL parent_id
419 entries would be constrained to reference valid rows of the table.
421 A table can have more than one foreign key constraint. This is used to
422 implement many-to-many relationships between tables. Say you have
423 tables about products and orders, but now you want to allow one order
424 to contain possibly many products (which the structure above did not
425 allow). You could use this table structure:
426 CREATE TABLE products (
427 product_no integer PRIMARY KEY,
432 CREATE TABLE orders (
433 order_id integer PRIMARY KEY,
434 shipping_address text,
438 CREATE TABLE order_items (
439 product_no integer REFERENCES products,
440 order_id integer REFERENCES orders,
442 PRIMARY KEY (product_no, order_id)
445 Notice that the primary key overlaps with the foreign keys in the last
448 We know that the foreign keys disallow creation of orders that do not
449 relate to any products. But what if a product is removed after an order
450 is created that references it? SQL allows you to handle that as well.
451 Intuitively, we have a few options:
452 * Disallow deleting a referenced product
453 * Delete the orders as well
456 To illustrate this, let's implement the following policy on the
457 many-to-many relationship example above: when someone wants to remove a
458 product that is still referenced by an order (via order_items), we
459 disallow it. If someone removes an order, the order items are removed
461 CREATE TABLE products (
462 product_no integer PRIMARY KEY,
467 CREATE TABLE orders (
468 order_id integer PRIMARY KEY,
469 shipping_address text,
473 CREATE TABLE order_items (
474 product_no integer REFERENCES products ON DELETE RESTRICT,
475 order_id integer REFERENCES orders ON DELETE CASCADE,
477 PRIMARY KEY (product_no, order_id)
480 The default ON DELETE action is ON DELETE NO ACTION; this does not need
481 to be specified. This means that the deletion in the referenced table
482 is allowed to proceed. But the foreign-key constraint is still required
483 to be satisfied, so this operation will usually result in an error. But
484 checking of foreign-key constraints can also be deferred to later in
485 the transaction (not covered in this chapter). In that case, the NO
486 ACTION setting would allow other commands to “fix” the situation before
487 the constraint is checked, for example by inserting another suitable
488 row into the referenced table or by deleting the now-dangling rows from
489 the referencing table.
491 RESTRICT is a stricter setting than NO ACTION. It prevents deletion of
492 a referenced row. RESTRICT does not allow the check to be deferred
493 until later in the transaction.
495 CASCADE specifies that when a referenced row is deleted, row(s)
496 referencing it should be automatically deleted as well.
498 There are two other options: SET NULL and SET DEFAULT. These cause the
499 referencing column(s) in the referencing row(s) to be set to nulls or
500 their default values, respectively, when the referenced row is deleted.
501 Note that these do not excuse you from observing any constraints. For
502 example, if an action specifies SET DEFAULT but the default value would
503 not satisfy the foreign key constraint, the operation will fail.
505 The appropriate choice of ON DELETE action depends on what kinds of
506 objects the related tables represent. When the referencing table
507 represents something that is a component of what is represented by the
508 referenced table and cannot exist independently, then CASCADE could be
509 appropriate. If the two tables represent independent objects, then
510 RESTRICT or NO ACTION is more appropriate; an application that actually
511 wants to delete both objects would then have to be explicit about this
512 and run two delete commands. In the above example, order items are part
513 of an order, and it is convenient if they are deleted automatically if
514 an order is deleted. But products and orders are different things, and
515 so making a deletion of a product automatically cause the deletion of
516 some order items could be considered problematic. The actions SET NULL
517 or SET DEFAULT can be appropriate if a foreign-key relationship
518 represents optional information. For example, if the products table
519 contained a reference to a product manager, and the product manager
520 entry gets deleted, then setting the product's product manager to null
521 or a default might be useful.
523 The actions SET NULL and SET DEFAULT can take a column list to specify
524 which columns to set. Normally, all columns of the foreign-key
525 constraint are set; setting only a subset is useful in some special
526 cases. Consider the following example:
527 CREATE TABLE tenants (
528 tenant_id integer PRIMARY KEY
532 tenant_id integer REFERENCES tenants ON DELETE CASCADE,
533 user_id integer NOT NULL,
534 PRIMARY KEY (tenant_id, user_id)
538 tenant_id integer REFERENCES tenants ON DELETE CASCADE,
539 post_id integer NOT NULL,
541 PRIMARY KEY (tenant_id, post_id),
542 FOREIGN KEY (tenant_id, author_id) REFERENCES users ON DELETE SET NULL (auth
546 Without the specification of the column, the foreign key would also set
547 the column tenant_id to null, but that column is still required as part
550 Analogous to ON DELETE there is also ON UPDATE which is invoked when a
551 referenced column is changed (updated). The possible actions are the
552 same, except that column lists cannot be specified for SET NULL and SET
553 DEFAULT. In this case, CASCADE means that the updated values of the
554 referenced column(s) should be copied into the referencing row(s).
555 There is also a noticeable difference between ON UPDATE NO ACTION (the
556 default) and ON UPDATE RESTRICT. The former will allow the update to
557 proceed and the foreign-key constraint will be checked against the
558 state after the update. The latter will prevent the update to run even
559 if the state after the update would still satisfy the constraint. This
560 prevents updating a referenced row to a value that is distinct but
561 compares as equal (for example, a character string with a different
562 case variant, if a character string type with a case-insensitive
565 Normally, a referencing row need not satisfy the foreign key constraint
566 if any of its referencing columns are null. If MATCH FULL is added to
567 the foreign key declaration, a referencing row escapes satisfying the
568 constraint only if all its referencing columns are null (so a mix of
569 null and non-null values is guaranteed to fail a MATCH FULL
570 constraint). If you don't want referencing rows to be able to avoid
571 satisfying the foreign key constraint, declare the referencing
572 column(s) as NOT NULL.
574 A foreign key must reference columns that either are a primary key or
575 form a unique constraint, or are columns from a non-partial unique
576 index. This means that the referenced columns always have an index to
577 allow efficient lookups on whether a referencing row has a match. Since
578 a DELETE of a row from the referenced table or an UPDATE of a
579 referenced column will require a scan of the referencing table for rows
580 matching the old value, it is often a good idea to index the
581 referencing columns too. Because this is not always needed, and there
582 are many choices available on how to index, the declaration of a
583 foreign key constraint does not automatically create an index on the
586 More information about updating and deleting data is in Chapter 6. Also
587 see the description of foreign key constraint syntax in the reference
588 documentation for CREATE TABLE.
590 5.5.6. Exclusion Constraints #
592 Exclusion constraints ensure that if any two rows are compared on the
593 specified columns or expressions using the specified operators, at
594 least one of these operator comparisons will return false or null. The
596 CREATE TABLE circles (
598 EXCLUDE USING gist (c WITH &&)
601 See also CREATE TABLE ... CONSTRAINT ... EXCLUDE for details.
603 Adding an exclusion constraint will automatically create an index of
604 the type specified in the constraint declaration.