Home Explore Blog CI



postgresql

9th chunk of `doc/src/sgml/ddl.sgml`
3c787d1c8a5628b6bfd4a84eba6f63ca6a06e1ad78ec665f0000000100000fa0
 separate name.  This clarifies
    error messages and allows you to refer to the constraint when you
    need to change it.  The syntax is:
<programlisting>
CREATE TABLE products (
    product_no integer,
    name text,
    price numeric <emphasis>CONSTRAINT positive_price</emphasis> CHECK (price &gt; 0)
);
</programlisting>
    So, to specify a named constraint, use the key word
    <literal>CONSTRAINT</literal> followed by an identifier followed
    by the constraint definition.  (If you don't specify a constraint
    name in this way, the system chooses a name for you.)
   </para>

   <para>
    A check constraint can also refer to several columns.  Say you
    store a regular price and a discounted price, and you want to
    ensure that the discounted price is lower than the regular price:
<programlisting>
CREATE TABLE products (
    product_no integer,
    name text,
    price numeric CHECK (price &gt; 0),
    discounted_price numeric CHECK (discounted_price &gt; 0),
    <emphasis>CHECK (price &gt; discounted_price)</emphasis>
);
</programlisting>
   </para>

   <para>
    The first two constraints should look familiar.  The third one
    uses a new syntax.  It is not attached to a particular column,
    instead it appears as a separate item in the comma-separated
    column list.  Column definitions and these constraint
    definitions can be listed in mixed order.
   </para>

   <para>
    We say that the first two constraints are column constraints, whereas the
    third one is a table constraint because it is written separately
    from any one column definition.  Column constraints can also be
    written as table constraints, while the reverse is not necessarily
    possible, since a column constraint is supposed to refer to only the
    column it is attached to.  (<productname>PostgreSQL</productname> doesn't
    enforce that rule, but you should follow it if you want your table
    definitions to work with other database systems.)  The above example could
    also be written as:
<programlisting>
CREATE TABLE products (
    product_no integer,
    name text,
    price numeric,
    CHECK (price &gt; 0),
    discounted_price numeric,
    CHECK (discounted_price &gt; 0),
    CHECK (price &gt; discounted_price)
);
</programlisting>
    or even:
<programlisting>
CREATE TABLE products (
    product_no integer,
    name text,
    price numeric CHECK (price &gt; 0),
    discounted_price numeric,
    CHECK (discounted_price &gt; 0 AND price &gt; discounted_price)
);
</programlisting>
    It's a matter of taste.
   </para>

   <para>
    Names can be assigned to table constraints in the same way as
    column constraints:
<programlisting>
CREATE TABLE products (
    product_no integer,
    name text,
    price numeric,
    CHECK (price &gt; 0),
    discounted_price numeric,
    CHECK (discounted_price &gt; 0),
    <emphasis>CONSTRAINT valid_discount</emphasis> CHECK (price &gt; discounted_price)
);
</programlisting>
   </para>

   <indexterm>
    <primary>null value</primary>
    <secondary sortas="check constraints">with check constraints</secondary>
   </indexterm>

   <para>
    It should be noted that a check constraint is satisfied if the
    check expression evaluates to true or the null value.  Since most
    expressions will evaluate to the null value if any operand is null,
    they will not prevent null values in the constrained columns.  To
    ensure that a column does not contain null values, the not-null
    constraint described in the next section can be used.
   </para>

   <note>
    <para>
     <productname>PostgreSQL</productname> does not support
     <literal>CHECK</literal> constraints that reference table data other than
     the new or updated row being checked.  While a <literal>CHECK</literal>
     constraint that violates this rule may appear to work in simple
     tests, it cannot guarantee that the database will not reach a state
     in which the constraint condition is false (due to subsequent

Title: Check Constraints: Column vs. Table Constraints, Null Values, and Limitations
Summary
This section delves deeper into check constraints, differentiating between column constraints (defined within a column definition) and table constraints (defined separately). It explains that table constraints can reference multiple columns, offering flexibility in defining complex relationships. The section also clarifies that check constraints are satisfied by true or null values, so additional measures like the not-null constraint are needed to prevent null values. Finally, it notes PostgreSQL's limitation on check constraints referencing other table data beyond the current row.