mirror of
https://github.com/postgres/postgres.git
synced 2025-05-28 00:03:23 -04:00
947 lines
32 KiB
Plaintext
947 lines
32 KiB
Plaintext
<!--
|
|
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_table.sgml,v 1.59 2002/11/21 23:34:43 petere Exp $
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="SQL-CREATETABLE">
|
|
<refmeta>
|
|
<refentrytitle id="sql-createtable-title">CREATE TABLE</refentrytitle>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>CREATE TABLE</refname>
|
|
<refpurpose>define a new table</refpurpose>
|
|
</refnamediv>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable class="PARAMETER">table_name</replaceable> (
|
|
{ <replaceable class="PARAMETER">column_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [ DEFAULT <replaceable>default_expr</> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [, ... ] ]
|
|
| <replaceable>table_constraint</replaceable> } [, ... ]
|
|
)
|
|
[ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
|
|
[ WITH OIDS | WITHOUT OIDS ]
|
|
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
|
|
|
|
where <replaceable class="PARAMETER">column_constraint</replaceable> is:
|
|
|
|
[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
|
|
{ NOT NULL | NULL | UNIQUE | PRIMARY KEY |
|
|
CHECK (<replaceable class="PARAMETER">expression</replaceable>) |
|
|
REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL ]
|
|
[ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
|
|
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
|
|
|
|
and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
|
|
|
[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
|
|
{ UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) |
|
|
PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) |
|
|
CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) |
|
|
FOREIGN KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> [, ... ] ) ]
|
|
[ MATCH FULL | MATCH PARTIAL ] [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
|
|
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
|
|
</synopsis>
|
|
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1 id="SQL-CREATETABLE-description">
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>CREATE TABLE</command> will create a new, initially empty table
|
|
in the current database. The table will be owned by the user issuing the
|
|
command.
|
|
</para>
|
|
|
|
<para>
|
|
If a schema name is given (for example, <literal>CREATE TABLE
|
|
myschema.mytable ...</>) then the table is created in the
|
|
specified schema. Otherwise it is created in the current schema (the one
|
|
at the front of the search path; see <literal>CURRENT_SCHEMA()</>).
|
|
TEMP tables exist in a special schema, so a schema name may not be
|
|
given when creating a TEMP table.
|
|
The table name must be distinct from the name of any other table,
|
|
sequence, index, or view in the same schema.
|
|
</para>
|
|
|
|
<para>
|
|
<command>CREATE TABLE</command> also automatically creates a data
|
|
type that represents the tuple type (structure type) corresponding
|
|
to one row of the table. Therefore, tables cannot have the same
|
|
name as any existing data type in the same schema.
|
|
</para>
|
|
|
|
<para>
|
|
A table cannot have more than 1600 columns. (In practice, the
|
|
effective limit is lower because of tuple-length constraints).
|
|
</para>
|
|
|
|
<para>
|
|
The optional constraint clauses specify constraints (or tests) that
|
|
new or updated rows must satisfy for an insert or update operation
|
|
to succeed. 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 table.
|
|
</para>
|
|
|
|
<para>
|
|
There are two ways to define constraints: table constraints and
|
|
column constraints. A column constraint is defined as part of a
|
|
column definition. A table constraint definition is not tied to a
|
|
particular column, and it can encompass more than one column.
|
|
Every column constraint can also be written as a table constraint;
|
|
a column constraint is only a notational convenience if the
|
|
constraint only affects one column.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry>
|
|
<term><literal>[LOCAL] TEMPORARY</> or <literal>[LOCAL] TEMP</></term>
|
|
<listitem>
|
|
<para>
|
|
If specified, the table is created as a temporary table.
|
|
Temporary tables are automatically dropped at the end of a
|
|
session, or optionally at the end of the current transaction
|
|
(see ON COMMIT below). Existing permanent tables with the same
|
|
name are not visible to the current session while the temporary
|
|
table exists, unless they are referenced with schema-qualified
|
|
names. Any indexes created on a temporary table are automatically
|
|
temporary as well.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>LOCAL</literal> word is optional. But see under
|
|
<xref linkend="sql-createtable-compatibility"
|
|
endterm="sql-createtable-compatibility-title">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">table_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name (optionally schema-qualified) of the table to be created.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">column_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name of a column to be created in the new table.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">data_type</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The data type of the column. This may include array specifiers.
|
|
Refer to the <citetitle>User's Guide</citetitle> for further
|
|
information about data types and arrays.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>DEFAULT
|
|
<replaceable>default_expr</replaceable></literal></term>
|
|
<listitem>
|
|
<para>
|
|
The <literal>DEFAULT</> clause assigns a default data value for
|
|
the column whose column definition it appears within. The value
|
|
is any variable-free expression (subselects and cross-references
|
|
to other columns in the current table are not allowed). The
|
|
data type of the default expression must match the data type of the
|
|
column.
|
|
</para>
|
|
|
|
<para>
|
|
The default expression will be used in any insert operation that
|
|
does not specify a value for the column. If there is no default
|
|
for a column, then the default is NULL.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>INHERITS ( <replaceable>parent_table</replaceable> [, ... ] )</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The optional <literal>INHERITS</> clause specifies a list of
|
|
tables from which the new table automatically inherits all
|
|
columns. If the same column name exists in more than one parent
|
|
table, an error is reported unless the data types of the columns
|
|
match in each of the parent tables. If there is no conflict,
|
|
then the duplicate columns are merged to form a single column in
|
|
the new table. If the column name list of the new table
|
|
contains a column that is also inherited, the data type must
|
|
likewise match the inherited column(s), and the column
|
|
definitions are merged into one. However, inherited and new
|
|
column declarations of the same name need not specify identical
|
|
constraints: all constraints provided from any declaration are
|
|
merged together and all are applied to the new table. If the
|
|
new table explicitly specifies a default value for the column,
|
|
this default overrides any defaults from inherited declarations
|
|
of the column. Otherwise, any parents that specify default
|
|
values for the column must all specify the same default, or an
|
|
error will be reported.
|
|
</para>
|
|
<!--
|
|
<para>
|
|
<application>PostgreSQL</application> automatically allows the
|
|
created table to inherit
|
|
functions on tables above it in the inheritance hierarchy; that
|
|
is, if we create table <literal>foo</literal> inheriting from
|
|
<literal>bar</literal>, then functions that accept the tuple
|
|
type <literal>bar</literal> can also be applied to instances of
|
|
<literal>foo</literal>. (Currently, this works reliably for
|
|
functions on the first or only parent table, but not so well for
|
|
functions on additional parents.)
|
|
</para>
|
|
-->
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>WITH OIDS</> or <literal>WITHOUT OIDS</></term>
|
|
<listitem>
|
|
<para>
|
|
This optional clause specifies whether rows of the new table
|
|
should have OIDs (object identifiers) assigned to them. The
|
|
default is to have OIDs. (If the new table inherits from any
|
|
tables that have OIDs, then <literal>WITH OIDS</> is forced even
|
|
if the command says <literal>WITHOUT OIDS</>.)
|
|
</para>
|
|
|
|
<para>
|
|
Specifying <literal>WITHOUT OIDS</> allows the user to suppress
|
|
generation of OIDs for rows of a table. This may be worthwhile
|
|
for large tables, since it will reduce OID consumption and
|
|
thereby postpone wraparound of the 32-bit OID counter. Once the
|
|
counter wraps around, uniqueness of OIDs can no longer be
|
|
assumed, which considerably reduces their usefulness.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable></literal></term>
|
|
<listitem>
|
|
<para>
|
|
An optional name for a column or table constraint. If not specified,
|
|
the system generates a name.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>NOT NULL</></term>
|
|
<listitem>
|
|
<para>
|
|
The column is not allowed to contain NULL values.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>NULL</></term>
|
|
<listitem>
|
|
<para>
|
|
The column is allowed to contain NULL values. This is the default.
|
|
</para>
|
|
|
|
<para>
|
|
This clause is only available for compatibility with
|
|
non-standard SQL databases. Its use is discouraged in new
|
|
applications.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>UNIQUE</> (column constraint)</term>
|
|
<term><literal>UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] )</> (table constraint)</term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The <literal>UNIQUE</literal> 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.
|
|
</para>
|
|
|
|
<para>
|
|
For the purpose of a unique constraint, NULL values are not
|
|
considered equal.
|
|
</para>
|
|
|
|
<para>
|
|
Each unique table constraint must name a set of columns that is
|
|
different from the set of columns named by any other unique or
|
|
primary key constraint defined for the table. (Otherwise it
|
|
would just be the same constraint listed twice.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>PRIMARY KEY</> (column constraint)</term>
|
|
<term><literal>PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] )</> (table constraint)</term>
|
|
<listitem>
|
|
<para>
|
|
The primary key constraint specifies that a column or columns of a table
|
|
may contain only unique (non-duplicate), non-NULL values.
|
|
Technically, <literal>PRIMARY KEY</literal> is merely a
|
|
combination of <literal>UNIQUE</> and <literal>NOT NULL</>, but
|
|
identifying a set of columns as primary key also provides
|
|
meta-data about the design of the schema, as a primary key
|
|
implies that other tables
|
|
may rely on this set of columns as a unique identifier for rows.
|
|
</para>
|
|
|
|
<para>
|
|
Only one primary key can be specified for a table, whether as a
|
|
column constraint or a table constraint.
|
|
</para>
|
|
|
|
<para>
|
|
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.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>CHECK (<replaceable class="PARAMETER">expression</replaceable>)</literal></term>
|
|
<listitem>
|
|
<para>
|
|
<literal>CHECK</> clauses specify integrity constraints or tests
|
|
which new or updated rows must satisfy for an insert or update
|
|
operation to succeed. Each constraint must be an expression
|
|
producing a Boolean result. A condition appearing within a
|
|
column definition should reference that column's value only,
|
|
while a condition appearing as a table constraint may reference
|
|
multiple columns.
|
|
</para>
|
|
|
|
<para>
|
|
Currently, <literal>CHECK</literal> expressions cannot contain
|
|
subselects nor refer to variables other than columns of the
|
|
current row.
|
|
</para>
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
|
|
<varlistentry>
|
|
<term><literal>REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> ) ] [ MATCH <replaceable class="parameter">matchtype</replaceable> ] [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ]</literal> (column constraint)</term>
|
|
|
|
<term><literal>FOREIGN KEY ( <replaceable class="parameter">column</replaceable> [, ... ] )
|
|
REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] ) ]
|
|
[ MATCH <replaceable class="parameter">matchtype</replaceable> ]
|
|
[ ON DELETE <replaceable class="parameter">action</replaceable> ]
|
|
[ ON UPDATE <replaceable class="parameter">action</replaceable> ]</literal>
|
|
(table constraint)</term>
|
|
|
|
<listitem>
|
|
<para>
|
|
The <literal>REFERENCES</literal> column constraint specifies
|
|
that a group of one or more columns of the new table must only
|
|
contain values which match against values in the referenced
|
|
column(s) <replaceable class="parameter">refcolumn</replaceable>
|
|
of the referenced table <replaceable
|
|
class="parameter">reftable</replaceable>. If <replaceable
|
|
class="parameter">refcolumn</replaceable> is omitted, the
|
|
primary key of the <replaceable
|
|
class="parameter">reftable</replaceable> is used. The
|
|
referenced columns must be the columns of a unique or primary
|
|
key constraint in the referenced table.
|
|
</para>
|
|
|
|
<para>
|
|
A value added to these columns is matched against the values of
|
|
the referenced table and referenced columns using the given
|
|
match type. There are three match types: <literal>MATCH
|
|
FULL</>, <literal>MATCH PARTIAL</>, and a default match type if
|
|
none is specified. <literal>MATCH FULL</> will not allow one
|
|
column of a multicolumn 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. <literal>MATCH PARTIAL</> is not yet
|
|
implemented.
|
|
</para>
|
|
|
|
<para>
|
|
In addition, when the data in the referenced columns is changed,
|
|
certain actions are performed on the data in this table's
|
|
columns. The <literal>ON DELETE</literal> clause specifies the
|
|
action to do when a referenced row in the referenced table is
|
|
being deleted. Likewise, the <literal>ON UPDATE</literal>
|
|
clause specifies the action to perform 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 actually
|
|
changed, no action is done. There are the following possible
|
|
actions for each clause:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><literal>NO ACTION</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Produce an error indicating that the deletion or update
|
|
would create a foreign key constraint violation. This is
|
|
the default action.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>RESTRICT</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Same as <literal>NO ACTION</literal>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>CASCADE</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Delete any rows referencing the deleted row, or update the
|
|
value of the referencing column to the new value of the
|
|
referenced column, respectively.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SET NULL</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Set the referencing column values to NULL.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SET DEFAULT</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Set the referencing column values to their default value.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
<para>
|
|
If primary key column is updated frequently, it may be wise to
|
|
add an index to the <literal>REFERENCES</literal> column so that
|
|
<literal>NO ACTION</literal> and <literal>CASCADE</literal>
|
|
actions associated with the <literal>REFERENCES</literal>
|
|
column can be more efficiently performed.
|
|
</para>
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>DEFERRABLE</literal> or <literal>NOT DEFERRABLE</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This controls whether the constraint can be deferred. A
|
|
constraint that is not deferrable will be checked immediately
|
|
after every command. Checking of constraints that are
|
|
deferrable may be postponed until the end of the transaction
|
|
(using the <xref linkend="sql-set-constraints" endterm="sql-set-constraints-title"> command).
|
|
<literal>NOT DEFERRABLE</literal> is the default. Only foreign
|
|
key constraints currently accept this clause. All other
|
|
constraint types are not deferrable.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>INITIALLY IMMEDIATE</literal> or <literal>INITIALLY DEFERRED</literal></term>
|
|
<listitem>
|
|
<para>
|
|
If a constraint is deferrable, this clause specifies the default
|
|
time to check the constraint. If the constraint is
|
|
<literal>INITIALLY IMMEDIATE</literal>, it is checked after each
|
|
statement. This is the default. If the constraint is
|
|
<literal>INITIALLY DEFERRED</literal>, it is checked only at the
|
|
end of the transaction. The constraint check time can be
|
|
altered with the <xref linkend="sql-set-constraints" endterm="sql-set-constraints-title"> command.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>ON COMMIT</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The behavior of temporary tables at the end of a transaction
|
|
block can be controlled using <literal>ON COMMIT</literal>.
|
|
The three options are:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><literal>PRESERVE ROWS</literal></term>
|
|
<listitem>
|
|
<para>
|
|
No special action is taken at the ends of transactions.
|
|
This is the default behavior.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>DELETE ROWS</literal></term>
|
|
<listitem>
|
|
<para>
|
|
All rows in the temporary table will be deleted at the
|
|
end of each transaction block. Essentially, an automatic
|
|
<xref linkend="sql-truncate"> is done at each commit.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>DROP</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The temporary table will be dropped at the end of the current
|
|
transaction block.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1 id="SQL-CREATETABLE-diagnostics">
|
|
<title>Diagnostics</title>
|
|
|
|
<msgset>
|
|
<msgentry>
|
|
<msg>
|
|
<msgmain>
|
|
<msgtext>
|
|
<simpara><computeroutput>CREATE TABLE</computeroutput></simpara>
|
|
</msgtext>
|
|
</msgmain>
|
|
</msg>
|
|
|
|
<msgexplan>
|
|
<para>
|
|
Message returned if table is successfully created.
|
|
</para>
|
|
</msgexplan>
|
|
</msgentry>
|
|
|
|
|
|
<msgentry>
|
|
<msg>
|
|
<msgmain>
|
|
<msgtext>
|
|
<simpara><computeroutput>ERROR</computeroutput></simpara>
|
|
</msgtext>
|
|
</msgmain>
|
|
</msg>
|
|
|
|
<msgexplan>
|
|
<para>
|
|
Message returned if table creation failed. This is usually
|
|
accompanied by some descriptive text, such as:
|
|
<computeroutput>ERROR: Relation '<replaceable
|
|
class="parameter">table</replaceable>' already
|
|
exists</computeroutput>, which occurs at run time if the table
|
|
specified already exists in the database.
|
|
</para>
|
|
</msgexplan>
|
|
</msgentry>
|
|
</msgset>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1 id="SQL-CREATETABLE-notes">
|
|
<title>Notes</title>
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
Whenever an application makes use of OIDs to identify specific
|
|
rows of a table, it is recommended to create a unique constraint
|
|
on the <structfield>oid</> column of that table, to ensure that
|
|
OIDs in the table will indeed uniquely identify rows even after
|
|
counter wraparound. Avoid assuming that OIDs are unique across
|
|
tables; if you need a database-wide unique identifier, use the
|
|
combination of <structfield>tableoid</> and row OID for the
|
|
purpose. (It is likely that future <productname>PostgreSQL</>
|
|
releases will use a separate OID counter for each table, so that
|
|
it will be <emphasis>necessary</>, not optional, to include
|
|
<structfield>tableoid</> to have a unique identifier
|
|
database-wide.)
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
The use of <literal>WITHOUT OIDS</literal> is not recommended
|
|
for tables with no primary key, since without either an OID or a
|
|
unique data key, it is difficult to identify specific rows.
|
|
</para>
|
|
</tip>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<productname>PostgreSQL</productname> automatically creates an
|
|
index for each unique constraint and primary key constraint to
|
|
enforce the uniqueness. Thus, it is not necessary to create an
|
|
explicit index for primary key columns. (See <xref
|
|
linkend="sql-createindex" endterm="sql-createindex-title"> for more information.)
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
The SQL92 standard says that <literal>CHECK</> column constraints
|
|
may only refer to the column they apply to; only
|
|
<literal>CHECK</> table constraints may refer to multiple
|
|
columns. <productname>PostgreSQL</productname> does not enforce
|
|
this restriction; it treats column and table check constraints
|
|
alike.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Unique constraints and primary keys are not inherited in the
|
|
current implementation. This makes the combination of
|
|
inheritance and unique constraints rather dysfunctional.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1 id="SQL-CREATETABLE-examples">
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
Create table <structname>films</> and table
|
|
<structname>distributors</>:
|
|
|
|
<programlisting>
|
|
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
|
|
);
|
|
</programlisting>
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3) PRIMARY KEY DEFAULT NEXTVAL('serial'),
|
|
name VARCHAR(40) NOT NULL CHECK (name <> '')
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Create a table with a 2-dimensional array:
|
|
|
|
<programlisting>
|
|
CREATE TABLE array (
|
|
vector INT[][]
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Define a unique table constraint for the table films. Unique table
|
|
constraints can be defined on one or more columns of the table:
|
|
|
|
<programlisting>
|
|
CREATE TABLE films (
|
|
code CHAR(5),
|
|
title VARCHAR(40),
|
|
did DECIMAL(3),
|
|
date_prod DATE,
|
|
kind VARCHAR(10),
|
|
len INTERVAL HOUR TO MINUTE,
|
|
CONSTRAINT production UNIQUE(date_prod)
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Define a check column constraint:
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3) CHECK (did > 100),
|
|
name VARCHAR(40)
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Define a check table constraint:
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3),
|
|
name VARCHAR(40)
|
|
CONSTRAINT con1 CHECK (did > 100 AND name <> '')
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Define a primary key table constraint for the table
|
|
<structname>films</>. Primary key table constraints can be defined
|
|
on one or more columns of the table.
|
|
|
|
<programlisting>
|
|
CREATE TABLE films (
|
|
code CHAR(5),
|
|
title VARCHAR(40),
|
|
did DECIMAL(3),
|
|
date_prod DATE,
|
|
kind VARCHAR(10),
|
|
len INTERVAL HOUR TO MINUTE,
|
|
CONSTRAINT code_title PRIMARY KEY(code,title)
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Define a primary key constraint for table
|
|
<structname>distributors</>. The following two examples are
|
|
equivalent, the first using the table constraint syntax, the second
|
|
the column constraint notation.
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3),
|
|
name CHAR VARYING(40),
|
|
PRIMARY KEY(did)
|
|
);
|
|
</programlisting>
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3) PRIMARY KEY,
|
|
name VARCHAR(40)
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
This assigns a literal constant default value for the column
|
|
<literal>name</literal>, and arranges for the default value of
|
|
column <literal>did</literal> to be generated by selecting the next
|
|
value of a sequence object. The default value of
|
|
<literal>modtime</literal> will be the time at which the row is
|
|
inserted.
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
name VARCHAR(40) DEFAULT 'luso films',
|
|
did INTEGER DEFAULT NEXTVAL('distributors_serial'),
|
|
modtime TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Define two <literal>NOT NULL</> column constraints on the table
|
|
<classname>distributors</classname>, one of which is explicitly
|
|
given a name:
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3) CONSTRAINT no_null NOT NULL,
|
|
name VARCHAR(40) NOT NULL
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Define a unique constraint for the <literal>name</literal> column:
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3),
|
|
name VARCHAR(40) UNIQUE
|
|
);
|
|
</programlisting>
|
|
|
|
The above is equivalent to the following specified as a table constraint:
|
|
|
|
<programlisting>
|
|
CREATE TABLE distributors (
|
|
did DECIMAL(3),
|
|
name VARCHAR(40),
|
|
UNIQUE(name)
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
</refsect1>
|
|
|
|
<refsect1 id="SQL-CREATETABLE-compatibility">
|
|
<title id="SQL-CREATETABLE-compatibility-title">Compatibility</title>
|
|
|
|
<para>
|
|
The <command>CREATE TABLE</command> conforms to SQL92 Intermediate
|
|
and to a subset of SQL99, with exceptions listed below and in the
|
|
descriptions above.
|
|
</para>
|
|
|
|
<refsect2>
|
|
<title>Temporary Tables</title>
|
|
|
|
<para>
|
|
In addition to the local temporary table, SQL92 also defines a
|
|
<literal>CREATE GLOBAL TEMPORARY TABLE</literal> statement.
|
|
Global temporary tables are also visible to other sessions.
|
|
</para>
|
|
|
|
<para>
|
|
For temporary tables, there is an optional <literal>ON COMMIT</literal> clause:
|
|
<synopsis>
|
|
CREATE { GLOBAL | LOCAL } TEMPORARY TABLE <replaceable class="parameter">table</replaceable> ( <replaceable class="parameter">...</replaceable> ) [ ON COMMIT { DELETE | PRESERVE } ROWS ]
|
|
</synopsis>
|
|
|
|
The <literal>ON COMMIT</literal> clause specifies whether or not
|
|
the temporary table should be emptied of rows whenever
|
|
<command>COMMIT</command> is executed. If the <literal>ON
|
|
COMMIT</> clause is omitted, SQL92 specifies that the default is
|
|
<literal>ON COMMIT DELETE ROWS</>. However, the behavior of
|
|
<productname>PostgreSQL</productname> is always like <literal>ON
|
|
COMMIT PRESERVE ROWS</literal>.
|
|
</para>
|
|
</refsect2>
|
|
|
|
<refsect2>
|
|
<title><literal>NULL</literal> <quote>Constraint</quote></title>
|
|
|
|
<para>
|
|
The <literal>NULL</> <quote>constraint</quote> (actually a
|
|
non-constraint) is a <productname>PostgreSQL</productname>
|
|
extension to SQL92 that is included for compatibility with some
|
|
other RDBMS (and for symmetry with the <literal>NOT
|
|
NULL</literal> constraint). Since it is the default for any
|
|
column, its presence is simply noise.
|
|
</para>
|
|
</refsect2>
|
|
|
|
<refsect2>
|
|
<title>Assertions</title>
|
|
|
|
<para>
|
|
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 table as constraints
|
|
are, so SQL92 provides the <command>CREATE ASSERTION</command>
|
|
statement as an alternate method for defining a constraint:
|
|
|
|
<synopsis>
|
|
CREATE ASSERTION <replaceable>name</replaceable> CHECK ( <replaceable>condition</replaceable> )
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</> does not implement assertions at present.
|
|
</para>
|
|
</refsect2>
|
|
|
|
<!--
|
|
<para>
|
|
Domain constraints are defined by CREATE DOMAIN or ALTER DOMAIN
|
|
statements:
|
|
</para>
|
|
<para>
|
|
Domain constraint:
|
|
|
|
<synopsis>
|
|
[ CONSTRAINT <replaceable>constraint_name</replaceable> ] CHECK <replaceable>constraint</replaceable>
|
|
[ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
|
|
[ [ NOT ] DEFERRABLE ]
|
|
</synopsis>
|
|
</para>
|
|
-->
|
|
|
|
<refsect2>
|
|
<title>Inheritance</title>
|
|
|
|
<para>
|
|
Multiple inheritance via the <literal>INHERITS</literal> clause is
|
|
a <productname>PostgreSQL</productname> language extension. SQL99
|
|
(but not SQL92) defines single inheritance using a different
|
|
syntax and different semantics. SQL99-style inheritance is not
|
|
yet supported by <productname>PostgreSQL</productname>.
|
|
</para>
|
|
</refsect2>
|
|
|
|
<refsect2>
|
|
<title>Object IDs</title>
|
|
|
|
<para>
|
|
The <productname>PostgreSQL</productname> concept of OIDs is not
|
|
standard.
|
|
</para>
|
|
</refsect2>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simplelist type="inline">
|
|
<member><xref linkend="sql-altertable" endterm="sql-altertable-title"></member>
|
|
<member><xref linkend="sql-droptable" endterm="sql-droptable-title"></member>
|
|
</simplelist>
|
|
</refsect1>
|
|
</refentry>
|
|
|
|
<!-- Keep this comment at the end of the file
|
|
Local variables:
|
|
mode: sgml
|
|
sgml-omittag:nil
|
|
sgml-shorttag:t
|
|
sgml-minimize-attributes:nil
|
|
sgml-always-quote-attributes:t
|
|
sgml-indent-step:1
|
|
sgml-indent-data:t
|
|
sgml-parent-document:nil
|
|
sgml-default-dtd-file:"../reference.ced"
|
|
sgml-exposed-tags:nil
|
|
sgml-local-catalogs:"/usr/lib/sgml/catalog"
|
|
sgml-local-ecat-files:nil
|
|
End:
|
|
-->
|