CREATE TABLE
  
  SQL - Language Statements
 
 
  
   CREATE TABLE
  
  
   Creates a new table
  
 
 
  
   2000-03-25
  
  
CREATE [ TEMPORARY | TEMP ] TABLE table (
    column type
    [ NULL | NOT NULL ] [ UNIQUE ] [ DEFAULT value ]
    [column_constraint_clause | PRIMARY KEY } [ ... ] ]
    [, ... ]
    [, PRIMARY KEY ( column [, ...] ) ]
    [, CHECK ( condition ) ]
    [, table_constraint_clause ]
    ) [ UNDER inherited_table [, ...] ]
  
  
  
   
    Inputs
   
   
    
     
      TEMPORARY
      
       
	The table is created only for this session, and is
	automatically dropped on session exit.
	Existing permanent tables with the same name are not visible
	while the temporary table exists.
       
      
     
     
      table
      
       
	The name of a new class or table to be created.
       
      
     
     
      column
      
       
	The name of a column.
       
      
     
     
      type
      
       
	The type of the column. This may include array specifiers.
	Refer to the PostgreSQL User's Guide for
	further information about data types and arrays.
       
      
     
     
      DEFAULT value
      
       
	A default value for a column.
	See the DEFAULT clause for more information.
       
      
     
     
      column_constraint_clause
      
       
	The optional column constraint clauses specify a list of
	integrity constraints or tests which new or updated entries must
	satisfy for an insert or update operation to succeed. Each
	constraint must evaluate to a boolean expression. Although
	SQL92 requires the column_constraint_clause to
	refer to that column only, Postgres
	allows multiple columns to be referenced within a single column
	constraint. See the column constraint clause for more
	information.
       
      
     
     
      table_constraint_clause
      
       
	The optional table CONSTRAINT clause specifies a
	list of integrity constraints which new or updated entries must
	satisfy for an insert or update operation to succeed. Each
	constraint must evaluate to a boolean expression. Multiple
	columns may be referenced within a single constraint. Only one
	PRIMARY KEY clause may be specified for a table;
	PRIMARY KEY column (a table
	constraint) and PRIMARY KEY (a column constraint)
	are mutually exclusive. See the table constraint clause for
	more information.
       
      
     
     
      UNDER inherited_table
      
       
	The optional UNDER clause specifies a collection of table
	names from which this table automatically inherits all fields.
	If any inherited field name appears more than once, 
	Postgres
	reports an error.
	Postgres automatically allows the created
	table to inherit functions on tables above it in the inheritance
	hierarchy.
       
      
     
    
       
  
  
   
    Outputs
   
   
    
     
      
CREATE
       
      
       
	Message returned if table is successfully created.
       
      
     
     
      
ERROR
       
      
       
	Message returned if table creation failed.
	This is usually accompanied by some descriptive text, such as:
	
ERROR:  Relation 'table' already exists
	
	, which occurs at runtime if the table specified already exists
	in the database.
       
      
     
     
      
ERROR:  DEFAULT: type mismatched
       
      
       
	If data type of default value doesn't match the
	column definition's data type.
       
      
     
    
   
  
 
 
  
   Description
  
  
   CREATE TABLE will enter a new class or table
   into the current data base. The table will be "owned" by the user issuing the
   command.
  
  
   Each type
   may be a simple type, a complex type (set) or an array type.
   Each attribute may be specified to be non-null and
   each may have a default value, specified by the
   .
  
  
   
    
     Consistent array dimensions within an
     attribute are not enforced. This will likely change in a future
     release.
    
   
  
  
   The optional UNDER
   clause specifies a collection of class names from which this class
   automatically inherits all fields.  If any inherited field name
   appears more than once, Postgres reports an error.  Postgres automatically
   allows the created class to inherit functions on classes above it in
   the inheritance hierarchy.  Inheritance of functions is done according
   to the conventions of the Common Lisp Object System (CLOS).
  
  
   Each new table or class table
   is automatically created as a type.  Therefore, one or more instances
   from the class are automatically a type and can be used in 
   
   or other CREATE TABLE statements.
  
  
   The new table is created as a heap with no initial data.
   A table can have no more than 1600 columns (in practice, the
   effective limit is lower because of tuple-length constraints).
   A table cannot have the same name as a system catalog table.
  
 
 
  
   DEFAULT Clause
  
  
   
DEFAULT value
   
  
  
   
    Inputs
   
   
    
     
      value
      
       
	The possible values for the default value expression are:
	
	 
	  
	   a literal value
	  
	 
	 
	  
	   a user function
	  
	 
	 
	  
	   a niladic function
	  
	 
	
       
      
     	
    
   
  
  
   
    Outputs
   
   
    None.
   
  
  
  
   
    Description
   
   
    The DEFAULT clause assigns a default data value to a column
    (via a column definition in the CREATE TABLE statement). 
    The data type of a default value must match the column definition's
    data type.
   
   
    An INSERT operation that includes a column without a specified
    default value will assign the NULL value to the column
    if no explicit data value is provided for it.
    Default literal means
    that the default is the specified constant value.
    Default niladic-function
    or user-function means
    that the default
    is the value of the specified function at the time of the INSERT.
   
   
    There are two types of niladic functions:
    
     
      niladic USER
      
       
	
	 CURRENT_USER / USER
	 
	  See CURRENT_USER function
	 
	
	
	 SESSION_USER
	 
	  See CURRENT_USER function
	 
	
	
	 SYSTEM_USER
	 
	  Not implemented
	 
	
       
      
     
     
      niladic datetime
      
       
	
	 CURRENT_DATE
	 
	  See CURRENT_DATE function
	 
	
	
	 CURRENT_TIME
	 
	  See CURRENT_TIME function
	 
	
	
	 CURRENT_TIMESTAMP
	 
	  See CURRENT_TIMESTAMP function
	 
	
       
      
     
    
   
  
  
   
    Usage
   
   
    To assign a constant value as the default for the
    columns did and number,
    and a string literal to the column did:
    
CREATE TABLE video_sales (
    did      VARCHAR(40) DEFAULT 'luso films',
    number   INTEGER DEFAULT 0,
    total    CASH DEFAULT '$0.0'
);
    
   
   
    To assign an existing sequence
    as the default for the column did,
    and a literal to the column name:
    
CREATE TABLE distributors (
    did      DECIMAL(3)  DEFAULT NEXTVAL('serial'),
    name     VARCHAR(40) DEFAULT 'luso films'
);
    
   
  
 
 
  
   Column CONSTRAINT Clause
  
  
   
[ CONSTRAINT name ] { [
    NULL | NOT NULL ] | UNIQUE | PRIMARY KEY | CHECK constraint | REFERENCES 
     reftable
     (refcolumn)
     [ MATCH matchtype ]
     [ ON DELETE action ] 
     [ ON UPDATE action ]
     [ [ NOT ] DEFERRABLE ] 
     [ INITIALLY checktime ] }
    [, ...]
   
  
  
   
    Inputs
   
   
    
     
      name
      
       
	An arbitrary name given to the integrity constraint. 
	If name is not specified,
	it is generated from the table and column names,
	which should ensure uniqueness for
	name.
       
      
     
     
      NULL
      
       
	The column is allowed to contain NULL values. This is the default.
       
      
     
     
      NOT NULL
      
       
	The column is not allowed to contain NULL values.
	This is equivalent to the column constraint
	CHECK (column NOT NULL).
       
      
     
     
      UNIQUE
      
       
	The column must have unique values. In Postgres
	this is enforced by an implicit creation of a unique index on the table.
       
      
     
     
      PRIMARY KEY
      
       
	This column is a primary key, which implies that uniqueness is
	enforced by the system and that other tables may rely on this
	column as a unique identifier for rows. See PRIMARY KEY for more
	information.
       
      
     
     
      
constraint
      
      
       
	The definition of the constraint.
       
      
     
    
   
  
  
   
    Description
   
   
    The optional constraint clauses specify constraints or tests which
    new or updated entries must satisfy for an insert or update
    operation to succeed. Each constraint must evaluate to a boolean
    expression. Multiple attributes may be referenced within a single
    constraint. The use of PRIMARY KEY as a table constraint is mutually
    incompatible with PRIMARY KEY as a column constraint.
   
   
    A constraint is a named rule: an SQL object which helps define
    valid sets of values by putting limits on the results of INSERT,
    UPDATE or DELETE operations performed on a Base Table. 
   
   
    There are two ways to define integrity constraints:
    table constraints, covered later, and column constraints, covered here.
   
   
    A column constraint is an integrity constraint defined as part of a
    column definition, and logically becomes a table constraint as soon
    as it is created. The column constraints available are:
    
     PRIMARY KEY
     REFERENCES
     UNIQUE
     CHECK
     NOT NULL
    
   
  
   
  
   
    NOT NULL Constraint
   
   
[ CONSTRAINT name ] NOT NULL 
   
   
    The NOT NULL constraint specifies a rule that a column may
    contain only non-null values. 
    This is a column constraint only, and not allowed
    as a table constraint.
   
   
    
     Outputs
    
    
     
      
       status
       
	
	 
	  
	   
ERROR:  ExecAppend: Fail to add null value in not null attribute "column".
	    
	   
	    
	     This error occurs at runtime if one tries to insert a null value
	     into a column which has a NOT NULL constraint.
	    
	   
	  
	 
	
       
      
      
    
   
   
    
     Description
    
    
    
   
   
    
     Usage
    
    
     Define two NOT NULL column constraints on the table
     distributors,
     one of which being a named constraint:
     
CREATE TABLE distributors (
    did      DECIMAL(3) CONSTRAINT no_null NOT NULL,
    name     VARCHAR(40) NOT NULL
);
     
    
   
  
  
   
    UNIQUE Constraint
   
   
[ CONSTRAINT name ] UNIQUE
   
   
    Inputs
    
     
      
       CONSTRAINT name
       
	
	 An arbitrary label given to a constraint.
	
       
      
     
    
   
   
   
    Outputs
    
     
      
       status
       
	
	 
	  
	   
ERROR: Cannot insert a duplicate key into a unique index.
	    
	   
	    
	     This error occurs at runtime if one tries to insert a
	     duplicate value into a column.
	    
	   
	  
	 
	
       
      
     
    
   
   
    
     Description
    
    
     The UNIQUE constraint specifies a rule that a group of one or
     more distinct columns of a table may contain only unique values.
    
    
     The column definitions of the specified columns do not have to
     include a NOT NULL constraint to be included in a UNIQUE
     constraint. Having more than one null value in a column without a
     NOT NULL constraint, does not violate a UNIQUE constraint. (This
     deviates from the SQL92 definition, but is a
     more sensible convention. See the section on compatibility for more
     details.)
    
    
     Each UNIQUE column constraint must name a column that is
     different from the set of columns named by any other UNIQUE or
     PRIMARY KEY constraint defined for the table.
    
    
     
      Postgres automatically creates a unique
      index for each UNIQUE constraint, to assure
      data integrity. See CREATE INDEX for more information.
     
    
   
   
    
     Usage
    
    
     Defines a UNIQUE column constraint for the table distributors.
     UNIQUE column constraints can only be defined on one column
     of the table:
     
CREATE TABLE distributors (
    did      DECIMAL(3),
    name     VARCHAR(40) UNIQUE
);
  
     which is equivalent to the following specified as a table constraint:
     
CREATE TABLE distributors (
    did      DECIMAL(3),
    name     VARCHAR(40),
    UNIQUE(name)
);
     
    
   
  
  
   
    The CHECK Constraint
   
   
[ CONSTRAINT name ] CHECK
    ( condition [, ...] ) 
   
   
    Inputs
    
     
      
       name
       
	
	 An arbitrary name given to a constraint.
	
       
      
      
       condition
       
	
	 Any valid conditional expression evaluating to a boolean result.
	
       
      
     
    
   
   
    
     Outputs
    
    
     
      
       status
       
	
	 
	  
	   
ERROR:  ExecAppend: rejected due to CHECK constraint "table_column".
	    
	   
	    
	     This error occurs at runtime if one tries to insert an illegal
	     value into a column subject to a CHECK constraint.
	    
	   
	  
	 
	
       
      
     
    
   
   
    Description
    
     The CHECK constraint specifies a restriction on allowed values
     within a column. The CHECK constraint is also allowed as a table
     constraint.
    
    
     The SQL92 CHECK column constraints can only be defined on, and
     refer to, one column of the table.
     Postgres does not have this restriction.
    
   
  
  
  
   
    PRIMARY KEY Constraint
   
   
[ CONSTRAINT name ] PRIMARY KEY 
   
   
    Inputs
    
     
      
       CONSTRAINT name
       
	
	 An arbitrary name for the constraint.
	
       
      
     
    
   
   
    Outputs
    
     
      
ERROR: Cannot insert a duplicate key into a unique index.
       
      
       
	This occurs at runtime if one tries to insert a duplicate value into
	a column subject to a PRIMARY KEY constraint.
       
      
     
    
   
   
    Description
    
     The PRIMARY KEY column constraint specifies that a column of a
     table may contain only unique (non-duplicate), non-NULL values. The
     definition of the specified column does not have to include an
     explicit NOT NULL constraint to be included in a PRIMARY KEY
     constraint.
    
    
     Only one PRIMARY KEY can be specified for a table.
    
   
   
    
     Notes
    
    
     Postgres automatically creates
     a unique index to assure
     data integrity (see CREATE INDEX statement).
    
    
     The PRIMARY KEY constraint should name a set of columns that is
     different from other sets of columns named by any UNIQUE constraint
     defined for the same table, since it will result in duplication
     of equivalent indexes and unproductive additional runtime overhead.
     However, Postgres does not specifically
     disallow this.
    
   
  
  
   
    2000-02-04
   
   
    REFERENCES Constraint
   
   
[ CONSTRAINT name ] REFERENCES reftable [ ( refcolumn ) ] 
    [ MATCH matchtype ]
    [ ON DELETE action ] 
    [ ON UPDATE action ]
    [ [ NOT ] DEFERRABLE ] 
    [ INITIALLY checktime ]
   
   
    The REFERENCES constraint specifies a rule that a column
    value is checked against the values of another column.
    REFERENCES can also be specified as part of
    a FOREIGN KEY table constraint.
   
   
    Inputs
    
     
      
       CONSTRAINT name
       
	
	 An arbitrary name for the constraint.
	
       
      
      
       reftable
       
        
         The table that contains the data to check against.
        
       
      
      
       refcolumn
       
        
         The column in reftable
         to check the data against.  If this is not specified, the PRIMARY KEY of the
         reftable is used.
        
       
      
      
       MATCH matchtype
       
        
         There are three match types: MATCH FULL, MATCH PARTIAL, and a
         default match type if none is specified. MATCH FULL will not
         allow one column of a multi-column foreign key to be NULL
         unless all foreign key columns are NULL. The default MATCH type
         allows a some foreign key columns to be NULL while other parts
         of the foreign key are not NULL. MATCH PARTIAL is currently not
	 supported.
        
       
      
      
       ON DELETE action
       
        
	 The action to do when a referenced row in the referenced table is being
         deleted.  There are the following actions.
         
          
           NO ACTION
           
            
             Produce error if foreign key violated.  This is the default.
            
           
          
          
           RESTRICT
           
            
             Same as NO ACTION.
            
           
          
          
           CASCADE
           
            
             Delete any rows referencing the deleted row.
            
           
          
          
           SET NULL
           
            
             Set the referencing column values to NULL.
            
           
          
          
           SET DEFAULT
           
            
             Set the referencing column values to their default value.
            
           
          
         
        
       
            
      
       ON UPDATE action
       
        
	 The action to do when a referenced column in the referenced
	 table is being updated to a new value. If the row is updated,
	 but the referenced column is not changed, no action is done.
	 There are the following actions.
         
          
           NO ACTION
           
            
             Produce error if foreign key violated.  This is the default.
            
           
          
          
           RESTRICT
           
            
             Same as NO ACTION.
            
           
          
          
           CASCADE
           
            
             Update the value of the referencing column to the new value of the
             referenced column.
            
           
          
          
           SET NULL
           
            
             Set the referencing column values to NULL.
            
           
          
          
           SET DEFAULT
           
            
             Set the referencing column values to their default value.
            
           
          
         
        
       
      
      
        [ NOT ] DEFERRABLE 
       
        
         This controls whether the constraint can be deferred to the end
         of the transaction. If DEFERRABLE, SET CONSTRAINTS ALL DEFERRED
         will cause the foreign key to be checked only at the end of the
         transaction. NOT DEFERRABLE is the default.
        
       
      
      
       INITIALLY checktime
       
        
         checktime has two possible values 
         which specify the default time to check the constraint.
         
          
           DEFERRED
	   
	    
	     Check constraint only at the end of the transaction.
	    
	   
          
          
           IMMEDIATE
	   
	    
	     Check constraint after each statement. This is the default.
	    
	   
	  
         
        
       
      
     
    
   
   
   
    
     2000-02-04
    
    
     Outputs
    
    
     
      
       status
       
	
	 
	  
	   
ERROR:  name referential integrity violation - key referenced from 
table not found in reftable
	    
	   
	    
             This error occurs at runtime if one tries to insert a value
             into a column which does not have a matching column in the
             referenced table.
	    
	   
	  
	 
	
       
      
      
    
   
   
    Description
    
     The REFERENCES column constraint specifies that a
     column of a table must only contain values which match against
     values in a referenced column of a referenced table.
    
    
     A value added to this column is matched against the values of the
     referenced table and referenced column using the given match type.
     In addition, when the referenced column data is changed, actions
     are run upon this column's matching data.
    
   
   
    
     1998-09-11
    
    
     Notes
    
    
     Currently Postgres only supports MATCH
     FULL and a default match type. In addition, the referenced
     columns are supposed to be the columns of a UNIQUE constraint in
     the referenced table, however Postgres
     does not enforce this.
    
   
  
 
 
 
  
   Table CONSTRAINT Clause
  
  
   
[ CONSTRAINT name ] { PRIMARY KEY |  UNIQUE } ( column [, ...] )
[ CONSTRAINT name ] CHECK ( constraint )
[ CONSTRAINT name ] FOREIGN KEY ( column [, ...] ) 
                     REFERENCES reftable
                      (refcolumn [, ...] )
                      [ MATCH matchtype ] 
                      [ ON DELETE action ] 
                      [ ON UPDATE action ]
                      [ [ NOT ] DEFERRABLE ] 
                      [ INITIALLY checktime ]
   
  
  
   
    Inputs
   
   
    
     
      CONSTRAINT name
      
       
	An arbitrary name given to an integrity constraint.
       
      
     
     
      column [, ...]
      
       
	The column name(s) for which to define a unique index
	and, for PRIMARY KEY, a NOT NULL constraint.
       
      
     
     
      CHECK ( constraint )
      
       
	A boolean expression to be evaluated as the constraint.
       
      
     
    
   
  
    
  
   
    Outputs
   
   
   
    The possible outputs for the table constraint clause are the same
    as for the corresponding portions of the column constraint clause.
   
  
  
  
   
    Description
   
   
   
    A table constraint is an integrity constraint defined on one or
    more columns of a base table. The four variations of "Table
    Constraint" are:
    
     UNIQUE
     CHECK
     PRIMARY KEY
     FOREIGN KEY
    
   
  
 
  
   
    UNIQUE Constraint
   
   
    
[ CONSTRAINT name ] UNIQUE ( column [, ...] )
    
   
   
    Inputs
    
     
      CONSTRAINT name
      
       
	An arbitrary name given to a constraint.
       
      
     
     
      column
      
       
	A name of a column in a table.
       
      
     
    
   
   
    Outputs
    
     
      
       status
       
	
	 
	  
	   ERROR: Cannot insert a duplicate key into a unique index
	   
	    
	     This error occurs at runtime if one tries to insert a
	     duplicate value into a column.
	    
	   
	  
	 
	
       
      
     
    
   
   
   
    
     Description
    
    
    
     The UNIQUE constraint specifies a rule that a group of one or more
     distinct columns of a table may contain only unique values. The
     behavior of the UNIQUE table constraint is the same as that for
     column constraints, with the additional capability to span multiple
     columns.
    
    
     See the section on the UNIQUE column constraint for more details.
    
   
   
    
     Usage
    
    
    
     Define a UNIQUE table constraint for the table distributors:
     
CREATE TABLE distributors (
    did      DECIMAL(3),
    name     VARCHAR(40),
    UNIQUE(name)
);
     
    
   
  
  
   
    PRIMARY KEY Constraint
   
   
    
[ CONSTRAINT name ] PRIMARY KEY ( column [, ...] ) 
    
   
   
    Inputs
    
     
      
       CONSTRAINT name
       
	
	 An arbitrary name for the constraint.
	
       
      
      
       column [, ...]
       
	
	 The names of one or more columns in the table.
	
       
      
     
    
   
   
   
    Outputs
    
     
      status
      
       
	
	 
	  ERROR: Cannot insert a duplicate key into a unique index.
	  
	   
	    This occurs at run-time if one tries to insert a duplicate
	    value into a column subject to a PRIMARY KEY constraint.
	   
	  
	 
	
       
      
     
    
   
   
   
    Description
    
     The PRIMARY KEY constraint specifies a rule that a group of one
     or more distinct columns of a table may contain only unique
     (nonduplicate), non-null values. The column definitions of
     the specified columns do not have to include a NOT NULL
     constraint to be included in a PRIMARY KEY constraint.
    
    
     The PRIMARY KEY table constraint is similar to that for column constraints,
     with the additional capability of encompassing multiple columns.
    
    
     Refer to the section on the PRIMARY KEY column constraint for more
     information.
    
   
  
  
   
    2000-02-04
   
   
    REFERENCES Constraint
   
   
[ CONSTRAINT name ] FOREIGN KEY ( column [, ...] )
    REFERENCES reftable [ ( refcolumn [, ...] ) ] 
    [ MATCH matchtype ]
    [ ON DELETE action ] 
    [ ON UPDATE action ]
    [ [ NOT ] DEFERRABLE ]
    [ INITIALLY checktime ]
   
   
    The REFERENCES constraint specifies a rule that a column value is
    checked against the values of another column. REFERENCES can also be
    specified as part of a FOREIGN KEY table constraint.
   
   
    Inputs
    
     
      
       CONSTRAINT name
       
	
	 An arbitrary name for the constraint.
	
       
      
      
       column [, ...]
       
	
	 The names of one or more columns in the table.
	
       
      
      
       reftable
       
        
         The table that contains the data to check against.
        
       
      
      
       referenced column [, ...]
       
        
         One or more column in the reftable
         to check the data against.  If this is not specified, the PRIMARY KEY of the
         reftable is used.
        
       
      
      
       MATCH matchtype
       
        
         There are three match types: MATCH FULL, MATCH PARTIAL, and a
         default match type if none is specified. MATCH FULL will not
         allow one column of a multi-column foreign key to be NULL
         unless all foreign key columns are NULL. The default MATCH type
         allows some foreign key columns to be NULL while other parts
         of the foreign key are not NULL. MATCH PARTIAL is currently not
	 supported.
        
       
      
      
       ON DELETE action
       
        
	 The action to do when a referenced row in the referenced table is being
         deleted.  There are the following actions.
         
          
           NO ACTION
           
            
             Produce error if foreign key violated.  This is the default.
            
           
          
          
           RESTRICT
           
            
             Same as NO ACTION.
            
           
          
          
           CASCADE
           
            
             Delete any rows referencing the deleted row.
            
           
          
          
           SET NULL
           
            
             Set the referencing column values to NULL.
            
           
          
          
           SET DEFAULT
           
            
             Set the referencing column values to their default value.
            
           
          
         
        
       
            
      
       ON UPDATE action
       
        
	 The action to do when a referenced column in the referenced
	 table is being updated to a new value. If the row is updated,
	 but the referenced column is not changed, no action is done.
	 There are the following actions.
         
          
           NO ACTION
           
            
             Produce error if foreign key violated.  This is the default.
            
           
          
          
           RESTRICT
           
            
             Disallow update of row being referenced.
            
           
          
          
           CASCADE
           
            
             Update the value of the referencing column to the new value
             of the referenced column.
            
           
          
          
           SET NULL
           
            
             Set the referencing column values to NULL.
            
           
          
          
           SET DEFAULT
           
            
             Set the referencing column values to their default value.
            
           
          
         
        
       
      
      
        [ NOT ] DEFERRABLE 
       
        
         This controls whether the constraint can be deferred to the end
         of the transaction. If DEFERRABLE, SET CONSTRAINTS ALL DEFERRED
         will cause the foreign key to be checked only at the end of the
         transaction. NOT DEFERRABLE is the default.
        
       
      
      
       INITIALLY checktime
       
        
         checktime has two
         possible values which specify the default time to check the
         constraint.
         
          
           IMMEDIATE
	   
	    
	     Check constraint after each statement. This is the default.
	    
	   
          
          
           DEFERRED
	   
	    
	     Check constraint only at the end of the transaction.
	    
	   
          
         
        
       
      
     
    
   
   
    
     2000-02-04
    
    
     Outputs
    
    
     
      
       status
       
	
	 
	  
	   
ERROR:  name referential integrity violation - key referenced from 
table not found in reftable
	    
	   
	    
             This error occurs at runtime if one tries to insert a value
             into a column which does not have a matching column in the
             referenced table.
	    
	   
	  
	 
	
       
      
      
    
   
   
    Description
    
     The FOREIGN KEY constraint specifies a rule that a group of one
     or more distinct columns of a table is related to a group
     of distinct columns in the referenced table.
    
    
     The FOREIGN KEY table constraint is similar to that for column
     constraints, with the additional capability of encompassing
     multiple columns.
    
    
     Refer to the section on the FOREIGN KEY column constraint for more
     information.
    
   
   
  
 
 
 
  
   Usage
  
  
   Create table films and table distributors:
   
CREATE TABLE films (
     code      CHARACTER(5) CONSTRAINT firstkey PRIMARY KEY,
     title     CHARACTER VARYING(40) NOT NULL,
     did       DECIMAL(3) NOT NULL,
     date_prod DATE,
     kind      CHAR(10),
     len       INTERVAL HOUR TO MINUTE
);
   
   
CREATE TABLE distributors (
     did      DECIMAL(3) PRIMARY KEY DEFAULT NEXTVAL('serial'),
     name     VARCHAR(40) NOT NULL CHECK (name <> '')
);
   
  
  
   Create a table with a 2-dimensional array:
   
   CREATE TABLE array (
          vector INT[][]
          );
   
  
  
   Define a UNIQUE table constraint for the table films.
   UNIQUE table constraints can be defined on one or more
   columns of the table:
   
CREATE TABLE films (
    code      CHAR(5),
    title     VARCHAR(40),
    did       DECIMAL(3),
    date_prod DATE,
    kind      CHAR(10),
    len       INTERVAL HOUR TO MINUTE,
    CONSTRAINT production UNIQUE(date_prod)
);
   
  
  
  
   Define a CHECK column constraint:
   
CREATE TABLE distributors (
    did      DECIMAL(3) CHECK (did > 100),
    name     VARCHAR(40)
);
   
  
  
   Define a CHECK table constraint:
   
CREATE TABLE distributors (
    did      DECIMAL(3),
    name     VARCHAR(40)
    CONSTRAINT con1 CHECK (did > 100 AND name > '')
);
   
  
 
  
   Define a PRIMARY KEY table constraint for the table films.
   PRIMARY KEY table constraints can be defined on one or more
   columns of the table:
   
CREATE TABLE films (
    code      CHAR(5),
    title     VARCHAR(40),
    did       DECIMAL(3),
    date_prod DATE,
    kind      CHAR(10),
    len       INTERVAL HOUR TO MINUTE,
    CONSTRAINT code_title PRIMARY KEY(code,title)
);
   
  
  
   Defines a PRIMARY KEY column constraint for table distributors.
   PRIMARY KEY column constraints can only be defined on one column
   of the table (the following two examples are equivalent):
   
CREATE TABLE distributors (
    did      DECIMAL(3),
    name     CHAR VARYING(40),
    PRIMARY KEY(did)
); 
   
   
CREATE TABLE distributors (
    did      DECIMAL(3) PRIMARY KEY,
    name     VARCHAR(40)
);
   
  
  
  
   
    Notes
   
   
    CREATE TABLE/UNDER is defined by SQL3. Multiple inheritance is a 
     Postgres language extension.
   
  
  
 
 
 
  
   Compatibility
  
  
   
    SQL92
   
   
    In addition to the locally visible temporary table, SQL92 also defines a
    CREATE GLOBAL TEMPORARY TABLE statement, and optionally an 
    ON COMMIT clause:
   
CREATE GLOBAL TEMPORARY TABLE table ( column type [
    DEFAULT value ] [ CONSTRAINT column_constraint ] [, ...] )
    [ CONSTRAINT table_constraint ] [ ON COMMIT { DELETE | PRESERVE } ROWS ] 
   
   
   
    For temporary tables, the CREATE GLOBAL TEMPORARY TABLE statement
    names a new table visible to other clients and defines the table's columns and
    constraints. 
   
   
    The optional ON COMMIT clause of CREATE TEMPORARY TABLE specifies
    whether or not the temporary table should be emptied of rows
    whenever COMMIT is executed. If the ON COMMIT clause is omitted, the
    default option, ON COMMIT DELETE ROWS, is assumed.
   
   
    To create a temporary table:
    
CREATE TEMPORARY TABLE actors (
    id         DECIMAL(3),
    name       VARCHAR(40),
    CONSTRAINT actor_id CHECK (id < 150)
) ON COMMIT DELETE ROWS;
    
   
   
    
     UNIQUE clause
    
    
     SQL92 specifies some additional capabilities for UNIQUE:
    
    
     Table Constraint definition:
     
[ CONSTRAINT name ] UNIQUE ( column [, ...] )
    [ { INITIALLY DEFERRED | INITIALLY IMMEDIATE } ]
    [ [ NOT ] DEFERRABLE ]
     
    
    
     Column Constraint definition:
     
[ CONSTRAINT name ] UNIQUE
      [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
      [ [ NOT ] DEFERRABLE ]
     
    
   
   
   
    
     NULL clause
    
    
	The NULL "constraint" (actually a non-constraint) is a
	Postgres extension to SQL92 is
	included for symmetry with the NOT NULL clause. Since it is the
	default for any column, its presence is simply noise.
     
[ CONSTRAINT name ] NULL 
     
    
   
   
   
    
     NOT NULL clause
    
    
     
     SQL92 specifies some additional capabilities for NOT NULL:
     
[ CONSTRAINT name ] NOT NULL 
    [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
    [ [ NOT ] DEFERRABLE ]
     
    
   
   
   
    
     CONSTRAINT clause
    
    
     SQL92 specifies some additional capabilities for constraints,
     and also defines assertions and domain constraints.
     
      
       Postgres does not yet support 
       either domains or assertions.
      
     
    
    
     An assertion is a special type of integrity constraint and shares
     the same namespace as other constraints. However, an assertion is
     not necessarily dependent on one particular base table as
     constraints are, so SQL-92 provides the CREATE ASSERTION statement
     as an alternate method for defining a constraint:
    
    
CREATE ASSERTION name CHECK ( condition )
    
    
    
     Domain constraints are defined by CREATE DOMAIN or ALTER DOMAIN
     statements:
    
    
     Domain constraint: 
     
[ CONSTRAINT name ] CHECK constraint 
    [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
    [ [ NOT ] DEFERRABLE ]
     
    
    
     Table constraint definition:
     
[ CONSTRAINT name ] { PRIMARY KEY ( column, ... ) | FOREIGN KEY constraint | UNIQUE constraint | CHECK constraint }
    [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
    [ [ NOT ] DEFERRABLE ]
     
    
    
     Column constraint definition:
     
[ CONSTRAINT name ] { NOT NULL | PRIMARY KEY | FOREIGN KEY constraint | UNIQUE | CHECK constraint }  
    [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
    [ [ NOT ] DEFERRABLE ]
     
    
    
     A CONSTRAINT definition may contain one deferment attribute
     clause and/or one initial constraint mode clause, in any order.
     
      
       NOT DEFERRABLE
       
	
         The constraint must be checked at the end of each statement.
         SET CONSTRAINTS ALL DEFERRED will have no effect on this type
         of constraint.
	
       
      
      
       DEFERRABLE
       
	
         This controls whether the constraint can be deferred to the end
         of the transaction. If SET CONSTRAINTS ALL DEFERRED is used or
         the constraint is set to INITIALLY DEFERRED, this will cause
         the foreign key to be checked only at the end of the
         transaction.
	
        
           
          SET CONSTRAINTS> changes the foreign key constraint mode
          only for the current transaction.
         
        
       
      
      
       INITIALLY IMMEDIATE
       
	
	 Check constraint only at the end of the transaction. This
	 is the default
	
       
      
      
       INITIALLY DEFERRED
       
	
	 Check constraint after each statement.
	
       
      
     
    
   
   
   
   
    
     CHECK clause
    
    
     SQL92 specifies some additional capabilities for CHECK in either
table or column constraints.
    
    
     table constraint definition:
     
[ CONSTRAINT name ] CHECK ( VALUE condition ) 
      [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
      [ [ NOT ] DEFERRABLE ]
     
    
    
     column constraint definition:
    
[ CONSTRAINT name ] CHECK ( VALUE condition ) 
      [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
      [ [ NOT ] DEFERRABLE ]
    
    
   
   
    
     PRIMARY KEY clause
    
    
     SQL92 specifies some additional capabilities for PRIMARY KEY:
    
    
     Table Constraint definition:
     
[ CONSTRAINT name ] PRIMARY KEY ( column [, ...] ) 
    [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
    [ [ NOT ] DEFERRABLE ]
     
    
    
     Column Constraint definition: 
     
[ CONSTRAINT name ] PRIMARY KEY 
    [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
    [ [ NOT ] DEFERRABLE ]